diff --git a/README.md b/README.md index a58af91..f766a4a 100644 --- a/README.md +++ b/README.md @@ -59,6 +59,7 @@ The package offers the following templates, some of them connect to the database - `node-react-todo`: A simple task manager template that uses Node.js and [React](https://react.dev/). It demonstrates the use of the database for Create, Read, Update and Delete (CRUD) operations. It is built by [vite](https://vitejs.dev/). - `ords-remix-jwt-sample`: A full stack Concert Application made with [Remix](https://remix.run/) that showcases the [Oracle REST Data Services](https://www.oracle.com/database/technologies/appdev/rest.html) functionalities. Some extra configuration is required, learn more about it in the `ords-remix-jwt-sample` [Getting Started Guide](/templates/ords-remix-jwt-sample/README.md#getting-started). - `mle-ts-sample`: A starter template application that demonstrates how backend applications can be developed using [Oracle Database Multilingual Engine (MLE)](https://docs.oracle.com/en/database/oracle/oracle-database/23/mlejs/introduction-to-mle.html). Requires SQLcl to be installed, for more information please read [README](/templates/mle-ts-sample/README.md) +- `mle-ts-ords-backend`: A starter template application that demonstrates how to expose MLE-based backend logic as RESTful endpoints using [Oracle REST Data Services](https://docs.oracle.com/en/database/oracle/oracle-rest-data-services/) (ORDS). This template requires both SQLcl and ORDS to be installed. For more information, please refer to the [README](/templates/mle-ts-ords-backend/). Each of the templates include documentation for you to get started with them, as well as NPM scripts for you to use right after generating the application. diff --git a/generators/index.ts b/generators/index.ts index 091b0e5..d729fb7 100644 --- a/generators/index.ts +++ b/generators/index.ts @@ -92,14 +92,34 @@ export default class extends Generator { const { protocol, hostname, port, serviceName } = retrieveConnectionStringDetailsFromORAFile( path.join( walletPath, 'tnsnames.ora' ) ); this.options.connectionString = generateConnectionString( protocol, hostname, port, serviceName ); } - // Copy files that are common to all of the templates. - this.fs.copyTpl( - this.templatePath( this.options.templateChoice ), - this.destinationPath(), - { - appName: this.options.appName - } - ); + if(this.options.templateChoice.includes('mle-ts-ords-backend')) { + const files = ['src/todos.ts', 'test/users.test.js', 'utils/db.mjs', 'utils/database/initdb.sql', 'utils/database/cleanup.sql', 'deploy.mjs', 'tsconfig.json','']; + files.forEach(file => { + this.fs.copyTpl( + this.templatePath(`../../templates/mle-ts-sample/${file}`), + this.destinationPath(file), + { + appName: this.options.appName + } + ); + }); + // Copy files that are common to all of the templates. + this.fs.copyTpl( + this.templatePath( this.options.templateChoice ), + this.destinationPath(), + this.options + ); + } else { + // Copy files that are common to all of the templates. + this.fs.copyTpl( + this.templatePath( this.options.templateChoice ), + this.destinationPath(), + { + appName: this.options.appName + } + ); + } + this.fs.copy( this.templatePath(`${ path.dirname( this.options.templateChoice ) }/app/.github`), this.destinationPath('.github') @@ -142,7 +162,7 @@ export default class extends Generator { this.templatePath( `${this.options.templateChoice}/.env.example` ), this.destinationPath( '.env.example' ), ); - } else if (this.options.templateChoice.includes('mle-ts-sample')) { + } else if (this.options.templateChoice.includes('mle-ts-sample') || this.options.templateChoice.includes('mle-ts-ords-backend')) { if( 'walletPath' in this.options ) { this.fs.copyTpl( this.templatePath( `${this.options.templateChoice}/.env.example.wallet` ), diff --git a/src/index.ts b/src/index.ts index 786b7ed..183a6a3 100644 --- a/src/index.ts +++ b/src/index.ts @@ -207,7 +207,7 @@ export default class Generate extends Command { 'template': Flags.string({ char: 't', description: 'Template to use', - options: ['node-vanilla', 'node-react', 'node-vue', 'node-react-todo', 'node-jet', 'node-angular', 'ords-remix-jwt-sample', 'mle-ts-sample'], + options: ['node-vanilla', 'node-react', 'node-vue', 'node-react-todo', 'node-jet', 'node-angular', 'ords-remix-jwt-sample', 'mle-ts-sample', 'mle-ts-ords-backend'], multiple: false }), @@ -314,6 +314,7 @@ export default class Generate extends Command { const databaseServiceName = flags['db-service-name'] ?? ''; const databaseUsername = flags['db-username'] ?? ''; const sqlclPath = flags['sqlcl'] ?? ''; + const ordsHost = flags['ords-host'] ?? ''; // TODO: Validate and use wallet path const walletPathDirectory = flags['wallet-path'] ? flags['wallet-path'] : ''; @@ -379,6 +380,11 @@ export default class Generate extends Command { value: 'mle-ts-sample', description: 'This creates an empty project with MLE and Oracle database connection starter code.' }, + { + name: 'mle-ts-ords-backend', + value: 'mle-ts-ords-backend', + description: 'Creates a starter project with MLE integration, Oracle Database connectivity, and scaffolded ORDS REST endpoints.' + }, ], pageSize: 10, default: 'node-vanilla' @@ -476,8 +482,10 @@ export default class Generate extends Command { // This will be config object for the basic connection type. Object.assign(configObject, { - connectionString: generateConnectionString( protocol, hostname, port, serviceValue ) - }); + connectionString: generateConnectionString( protocol, hostname, port, serviceValue ), + serviceValue: serviceValue, + databasePort: port + }); } else if( databaseConnectionType === 'walletPath' ) { let walletPath = ''; @@ -509,23 +517,29 @@ export default class Generate extends Command { // This is the config object that represents the wallet connection type. Object.assign(configObject, { walletPath: walletPath, - walletPassword: walletPassword + walletPassword: walletPassword, + serviceValue: "", + databasePort: 8080, }); } - if(templateChoice !== 'ords-remix-jwt-sample'){ + if(templateChoice !== 'ords-remix-jwt-sample') { // Ask the user for the database connection username. + let databaseUser = databaseUsername === '' ? await input( + { + message: 'What\'s your database username?', + validate ( input ) { + return input.trim().length === 0 ? 'This field cannot be empty!' : true; + } + }, + ) : databaseUsername; + if (templateChoice === 'mle-ts-ords-backend') { + databaseUser = databaseUser.toLowerCase(); + } Object.assign( configObject, { - connectionUsername: databaseUsername === '' ? await input( - { - message: 'What\'s your database username?', - validate ( input ) { - return input.trim().length === 0 ? 'This field cannot be empty!' : true; - } - }, - ) : databaseUsername - } ); - + connectionUsername: databaseUser + }); + // Ask the user for the database connection password. Object.assign( configObject, { connectionPassword: await password( @@ -540,7 +554,8 @@ export default class Generate extends Command { } ); } - if(templateChoice == 'mle-ts-sample'){ + if(templateChoice == 'mle-ts-sample' || templateChoice == 'mle-ts-ords-backend') + { // Ask the user for the path to SQLcl Object.assign( configObject, { sqlclPath: sqlclPath === '' ? await input( @@ -552,6 +567,21 @@ export default class Generate extends Command { }, ) : sqlclPath }); + if (templateChoice == 'mle-ts-ords-backend') + { + // Ask the user for the path to SQLcl + Object.assign( configObject, { + ordsHost: ordsHost === '' ? await input( + { + message: 'Please provide ORDS Base URL: ', + validate ( input ) { + return input.trim().length === 0 ? 'This field cannot be empty!' : true; + }, + default: 'http://localhost:8080/ords' + }, + ) : ordsHost + }); + } } generateDatabaseApp( configObject ); diff --git a/templates/mle-ts-ords-backend/.env.example b/templates/mle-ts-ords-backend/.env.example new file mode 100644 index 0000000..0bb6999 --- /dev/null +++ b/templates/mle-ts-ords-backend/.env.example @@ -0,0 +1,16 @@ +# Database User +DB_USER=<%= connectionUsername %> +# Database User Password +DB_PASSWORD=<%= connectionPassword %> +# Connection string to your Autonomous Database/ +# Oracle Database instance +CONNECT_STRING=<%= connectionString %> +# Oracle MLE Module name +MLE_MODULE= +# Optional HTTP Proxy Settings +# HTTPS_PROXY= +# HTTPS_PROXY_PORT= + +# Path to your local SQL Developer Command Line +# installation +SQL_CL_PATH=<%= sqlclPath %> \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/.env.example.wallet b/templates/mle-ts-ords-backend/.env.example.wallet new file mode 100644 index 0000000..c6bd847 --- /dev/null +++ b/templates/mle-ts-ords-backend/.env.example.wallet @@ -0,0 +1,19 @@ +# Path to database wallet +WALLET_PATH=<%= walletPath %> +WALLET_PASSWORD=<%= walletPassword %> +# Database User +DB_USER=<%= connectionUsername %> +# Database User Password +DB_PASSWORD=<%= connectionPassword %> +# Connection string to your Autonomous Database/ +# Oracle Database instance +CONNECT_STRING=<%= connectionString %> +# Oracle MLE Module name +MLE_MODULE= +# Optional HTTP Proxy Settings +# HTTPS_PROXY= +# HTTPS_PROXY_PORT= + +# Path to your local SQL Developer Command Line +# installation +SQL_CL_PATH=<%= sqlclPath %> \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/.gitignore.template b/templates/mle-ts-ords-backend/.gitignore.template new file mode 100644 index 0000000..c481026 --- /dev/null +++ b/templates/mle-ts-ords-backend/.gitignore.template @@ -0,0 +1,22 @@ +# Logs +logs +*.log +npm-debug.log* +yarn-debug.log* +yarn-error.log* +pnpm-debug.log* +lerna-debug.log* + +node_modules +dist +dist-ssr +*.local + +# Editor directories and files +.DS_Store + +/.env +/.env.* +!/.env.example +!/.env.*.example +/server/utils/db/wallet diff --git a/templates/mle-ts-ords-backend/README.md b/templates/mle-ts-ords-backend/README.md new file mode 100644 index 0000000..d700e84 --- /dev/null +++ b/templates/mle-ts-ords-backend/README.md @@ -0,0 +1,162 @@ + + +# In-Database JavaScript with ORDS Backend Template + +An application template for Typescript and JavaScript developers showcasing REST API development using Oracle REST Data Services (ORDS) and Multilingual Engine (MLE). +**Extends [`mle-ts-sample`](../mle-ts-sample/README.md); see that template's readme for foundational features and explanations.** + +## Description + +This project builds upon the [mle-ts-sample](../mle-ts-sample/README.md) template by demonstrating how to create REST APIs within Oracle Database using [Oracle REST Data Services (ORDS)](https://docs.oracle.com/en/database/oracle/oracle-rest-data-services/) and the [Multilingual Engine (MLE) JavaScript](https://docs.oracle.com/en/database/oracle/oracle-database/23/mlejs/introduction-to-mle.html). +In addition to the TODO functionality of `mle-ts-sample`, this template shows how to: + +- Configure ORDS modules, templates, and handlers using SQL. +- Export JavaScript functions as REST endpoints via ORDS, with handler logic in an MLE module. +- Test REST endpoints with HTTP requests. +- Set up a development environment using Docker Compose, with Oracle Database and an ORDS server. + +The basic application logic structure, build/deploy system, and database initialization approach remain as documented in the [mle-ts-sample README](../mle-ts-sample/README.md). + +### Project Structure + +Building on top of the standard [mle-ts-sample](../mle-ts-sample/README.md) layout, this template introduces several new files and conventions: + +| Source File | Used For | +| ---------------------------------- | ------------------------------------------------------------------------------------- | +| `src/ords.ts` | Contains handler functions for ORDS REST endpoints. | +| `src/index.ts` | Exports the public API for the MLE module (see mle-ts-sample), plus ORDS handler implementations. | +| `utils/database/ords.sql` | SQL script to configure ORDS: installs ORDS modules, templates, and handlers bound to the MLE JS module. | +| `test/rest.test.js` | Automated tests for the REST API endpoints, using HTTP requests against the running ORDS backend. | +| `docker-compose.yml` | Docker Compose file spinning up both Oracle Database 23 Free (`db23`) and an ORDS node (`ords-node1`). | +| `utils/database/setup/01-user-setup.sql` | Creates MLE enabled user. The script is run during docker container DB service startup. | + +All standard files and scripts from [`mle-ts-sample`](../mle-ts-sample/README.md) are also present and used as described in that README. + +### Requirements + +- [Oracle Database 23ai](https://www.oracle.com/database/) or Oracle Database Free (provided via Docker Compose). +- [Oracle REST Data Services](https://www.oracle.com/database/technologies/appdev/rest.html) (ORDS, configured for database access). +- [SQLcl](https://www.oracle.com/database/sqldeveloper/technologies/sqlcl) for deploying MLE modules. +- [Node.js](https://nodejs.org/). +- (Optional) [Docker](https://www.docker.com/) and [Docker Compose](https://docs.docker.com/compose/) for quick local setup. + _Note: Any suitable container engine, such as [Podman](https://podman.io/), can be used in place of Docker._ + +### 1. Create the Application + +Follow the general steps in the [mle-ts-sample/README](../mle-ts-sample/README.md#getting-started) to create your project, but **choose `mle-ts-ords-backend` as the template** during `@create-database-app` initialization. + +### 2. (Optional) Start Development Environment with Docker Compose + +To quickly launch both Oracle Database and ORDS locally: + +```bash +docker-compose up +``` +This starts: + +- `db23` - Oracle Database 23 Free +- `ords-node1` - ORDS server configured to use `db23` + +See the `docker-compose.yml` file (and its comments) for configuration options. + +### 3. Install Project Dependencies + +```bash +npm install +``` + +Installs all node modules, just like in mle-ts-sample. + +### 4. Initialize the Database + +Initialize the application data tables (as in mle-ts-sample): + +```bash +npm run initdb +``` + +### 5. Build and Deploy the MLE Module + +Build your application: + +```bash +npm run build +``` + +Deploy the transpiled JS module to the database: + +```bash +npm run deploy +``` + +Please check [mle-ts-sample/README](../mle-ts-sample/README.md) for more information about naming of the deployed modules. + +## REST Endpoint Development + +The main logic for REST endpoints is in [`src/ords.ts`](src/ords.ts). +This file exports handler functions used by ORDS to process REST requests. These handlers are linked to ORDS modules and templates via SQL in [`utils/database/ords.sql`](utils/database/ords.sql). + +> **Before running any REST API tests, you must deploy your ORDS configuration using:** +```bash +npm run ords +``` +> This command runs ['utils/ords.mjs'] script that reads ords.sql, replaces the module placeholder with your module name from .env (MLE_MODULE), and executes the SQL in the database to configure modules, templates, and handlers. + +- `src/index.ts` exports public functions and handlers for deployment as an MLE module. +- The generated ORDS configuration points to the correct JS handlers for each endpoint. + +## Application Testing + +### Testing REST API Endpoints + +After deploying the MLE module and executing the ORDS configuration (`utils/database/ords.sql`), you can test the exposed REST API endpoints. + +#### Automated Testing + +Run the REST API test suite (see [`test/rest.test.js`](test/rest.test.js)): + +```bash +npm run test +``` + +This will send HTTP requests to the running ORDS server and verify the responses against expectations. + +You can also use `curl`, `Postman`, or any HTTP client to manually test the REST endpoints. +Example (replace `[host]`, `[port]`, ``, and path as appropriate): + +```bash +curl -X GET "http://localhost:8080/ords///" +``` +Examples: +- Create user +```bash +curl --location --request POST 'http://localhost:8080/ords//users?name=' +``` +- Get user information +```bash +curl --location 'http://localhost:8080/ords//users/' +``` +- Get all users +```bash +curl --location 'http://localhost:8080/ords//users' +``` +- Update user information +```bash +curl --location --request PUT 'http://localhost:8080/ords//users/?name=' +``` +- Delete user +```bash +curl --location --request DELETE 'http://localhost:8080/ords//users/' +``` + +All endpoint routes, HTTP methods, and request/response formats are defined in the ORDS configuration and documented in `utils/database/ords.sql`. + +## Other Testing, Cleanup, and Usage + +You can use all application testing and database management approaches described in [mle-ts-sample/README](../mle-ts-sample/README.md) , including PLSQL call specifications, Oracle APEX, and other methods. + +## Links for Further Reading +- [mle-ts-sample/README](../mle-ts-sample/README.md) - foundational documentation for this template. +- [ORDS Documentation](https://docs.oracle.com/en/database/oracle/oracle-rest-data-services/index.html) +- [Docker Compose](https://docs.docker.com/compose/) +- [Podman Compose](https://docs.podman.io/en/v5.3.1/markdown/podman-compose.1.html) \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/docker-compose.yml b/templates/mle-ts-ords-backend/docker-compose.yml new file mode 100644 index 0000000..d62807c --- /dev/null +++ b/templates/mle-ts-ords-backend/docker-compose.yml @@ -0,0 +1,28 @@ +services: + db23: + hostname: database + image: container-registry.oracle.com/database/free:latest + environment: + - ORACLE_PDB=<%= serviceValue %> + - ORACLE_PWD=oracle + - DBHOST=database + volumes: + - ./utils/database/setup:/opt/oracle/scripts/startup + ports: + - <%= databasePort %>:1521 + mem_limit: 4096m + cpus: 2 + ords-node1: + hostname: ords-node + image: container-registry.oracle.com/database/ords:latest + environment: + - CONN_STRING=//database:1521/<%= serviceValue %> + - ORACLE_PWD=oracle + volumes: + - ./ords/config:/etc/ords/config + - ./apex:/opt/oracle/apex + ports: + - 8080:8080 + depends_on: + db23: + condition: service_healthy \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/package.json b/templates/mle-ts-ords-backend/package.json new file mode 100644 index 0000000..5467f41 --- /dev/null +++ b/templates/mle-ts-ords-backend/package.json @@ -0,0 +1,20 @@ +{ + "name": "mleapp", + "version": "1.0.0", + "devDependencies": { + "mle-js": "^23.7.0", + "typescript": "^5.7.3", + "esbuild": "0.25.1", + "oracledb": "^6.7.1", + "vitest": "^3.1.2", + "dotenv": "^16.5.0" + }, + "scripts": { + "build": "esbuild src/index.ts --bundle --minify=false --platform=neutral --format=esm --outfile=dist/index.js", + "deploy": "node deploy.mjs", + "initdb": "node utils/db.mjs utils/database/initdb.sql", + "cleandb": "node utils/db.mjs utils/database/cleanup.sql", + "ords": "node utils/ords.mjs", + "test": "vitest" + } +} \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/src/index.ts b/templates/mle-ts-ords-backend/src/index.ts new file mode 100644 index 0000000..f4909da --- /dev/null +++ b/templates/mle-ts-ords-backend/src/index.ts @@ -0,0 +1,3 @@ +export { createUserHandler, getUserHandler, getAllUsersHandler, deleteUserHandler, updateUserHandler } from './ords'; +//needed for basic tests of MLE module calls +export { newUser, getUser, getAllUsers, updateUser, deleteUser } from './todos'; \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/src/ords.ts b/templates/mle-ts-ords-backend/src/ords.ts new file mode 100644 index 0000000..113b2b9 --- /dev/null +++ b/templates/mle-ts-ords-backend/src/ords.ts @@ -0,0 +1,54 @@ +import { newUser, getUser, getAllUsers, deleteUser, updateUser } from './todos'; + +export async function createUserHandler(req, resp) { + const id = await newUser(req.query_parameters.name); + resp.status(201); + resp.content_type('application/json'); + resp.json({ id }); +} +export async function getUserHandler(req, resp) { + const userName = await getUser(parseInt(req.uri_parameters.id)); + if(!userName) { + resp.status(404); + resp.content_type('application/json'); + resp.json({msg: "User not found"}); + } else { + resp.status(200); + resp.content_type('application/json'); + resp.json(userName); + } +} + +export async function getAllUsersHandler(req, resp) { + const users = await getAllUsers(); + if(!users) { + resp.status(404); + resp.content_type('application/json'); + resp.json({msg: "User not found"}); + } else { + resp.status(200); + resp.content_type('application/json'); + resp.json(users); + } +} + +export async function deleteUserHandler(req, resp) { + const deleted = await deleteUser(parseInt(req.uri_parameters.id)); + if (deleted > 0) { + resp.status(200); + } else { + resp.status(404); + } + resp.content_type('application/json'); + resp.json({ rowsDeleted: deleted }); +} +export async function updateUserHandler(req, resp) { + const updated = await updateUser(parseInt(req.uri_parameters.id),req.query_parameters.name); + if (updated > 0) { + resp.status(200); + } else { + resp.status(404); + } + resp.content_type('application/json'); + resp.json({ rowsUpdated: updated }); +} diff --git a/templates/mle-ts-ords-backend/test/rest.test.js b/templates/mle-ts-ords-backend/test/rest.test.js new file mode 100644 index 0000000..e8bf2d4 --- /dev/null +++ b/templates/mle-ts-ords-backend/test/rest.test.js @@ -0,0 +1,101 @@ +import { beforeEach, afterEach, describe, it, expect } from 'vitest'; + +const BASE_URL = '<%= ordsHost %>/<%= connectionUsername %>'; +let createdUserId; +let skipCleanup = false; + + +beforeEach(async () => { + skipCleanup = false; + const res = await fetch(`${BASE_URL}/users?name=perry`, { method: 'POST' }); + const data = await res.json(); + createdUserId = data.id; +}); + +afterEach(async () => { + if (!skipCleanup) { + await fetch(`${BASE_URL}/users/${createdUserId}`, { method: 'DELETE' }); + } +}); + +describe('ORDS User Endpoints', () => { + it('should create a user (POST)', async () => { + expect(createdUserId).toBeDefined(); + expect(typeof createdUserId).toBe('number'); + }); + + it('should retrieve the created user (GET)', async () => { + const res = await fetch(`${BASE_URL}/users/${createdUserId}`); + expect(res.status).toBe(200); + const user = await res.json(); + expect(user).toBe('perry'); + console.log('User:', user); + }); + + it('should retrieve all created users (GET)', async () => { + const res = await fetch(`${BASE_URL}/users?name=perry`, { method: 'POST' }); + const data = await res.json(); + expect(data.id).toBeDefined(); + expect(typeof data.id).toBe('number'); + + const res1 = await fetch(`${BASE_URL}/users?name=perry1`, { method: 'POST' }); + const data1 = await res1.json(); + expect(data1.id).toBeDefined(); + expect(typeof data1.id).toBe('number'); + + const res2 = await fetch(`${BASE_URL}/users`); + expect(res2.status).toBe(200); + const users = await res2.json(); + const names = users.map((u) => u.NAME); + const ids = users.map((u) => u.ID); + expect(names).toContain('perry'); + expect(names).toContain('perry1'); + expect(ids).toContain(data1.id); + expect(ids).toContain(data.id); + + + const res3 = await fetch(`${BASE_URL}/users/${data.id}`, { method: 'DELETE' }); + expect(res3.status).toBe(200); + const result3 = await res3.json(); + expect(result3).toHaveProperty('rowsDeleted', 1); + + const res4 = await fetch(`${BASE_URL}/users/${data1.id}`, { method: 'DELETE' }); + expect(res4.status).toBe(200); + const result4 = await res4.json(); + expect(result4).toHaveProperty('rowsDeleted', 1); + }); + + it('should update the user name (PUT)', async () => { + const res = await fetch(`${BASE_URL}/users/${createdUserId}?name=Katty`, { + method: 'PUT' + }); + + expect(res.status).toBe(200); + const result = await res.json(); + expect(result).toHaveProperty('rowsUpdated', 1); + console.log('User updated'); + + //should confirm the user name was updated (GET) + const res1 = await fetch(`${BASE_URL}/users/${createdUserId}`); + expect(res1.status).toBe(200); + const user = await res1.json(); + expect(user).toBe('Katty'); + console.log('User:', user); + }); + + it('should delete the user (DELETE)', async () => { + const res = await fetch(`${BASE_URL}/users/${createdUserId}`, { method: 'DELETE' }); + expect(res.status).toBe(200); + const result = await res.json(); + expect(result).toHaveProperty('rowsDeleted', 1); + console.log('User deleted'); + + //should not find deleted user (GET) + const res1 = await fetch(`${BASE_URL}/users/${createdUserId}`); + expect(res1.status).toBe(404); + const result1 = await res1.json(); + expect(result1).toHaveProperty('msg', 'User not found'); + + skipCleanup = true; + }); +}); \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/utils/database/ords.sql b/templates/mle-ts-ords-backend/utils/database/ords.sql new file mode 100644 index 0000000..2f011ff --- /dev/null +++ b/templates/mle-ts-ords-backend/utils/database/ords.sql @@ -0,0 +1,157 @@ +create or replace MLE ENV USER_ENV imports ( + 'user_list' module __MODULE_PLACEHOLDER__ +); + +begin + ords.enable_schema; +end; +/ + +declare + c_module_name constant varchar2(255) := 'users'; +begin + ords.define_module( + p_module_name => c_module_name, + p_base_path => '/', + p_status => 'PUBLISHED', + p_items_per_page => 25 + ); +end; +/ +-------------------------------------------------------------------------------- +-- POST ords/<%= connectionUsername %>/users +-------------------------------------------------------------------------------- +declare + c_module_name constant varchar2(255) := 'users'; + c_pattern constant varchar2(255) := 'users'; +begin + ords.define_template( + p_module_name => c_module_name, + p_pattern => c_pattern + ); + + ords.define_handler( + p_module_name => c_module_name, + p_pattern => c_pattern, + p_method => 'POST', + p_source_type => 'mle/javascript', + p_mle_env_name => 'USER_ENV', + p_source => q'~ + (req, resp) => { + const { createUserHandler } = await import ('user_list'); + createUserHandler(req,resp); + } + ~' + ); + commit; +end; +/ + +-------------------------------------------------------------------------------- +-- GET ords/<%= connectionUsername %>/users +-------------------------------------------------------------------------------- +declare + c_module_name constant varchar2(255) := 'users'; + c_pattern constant varchar2(255) := 'users'; +begin + ords.define_handler( + p_module_name => c_module_name, + p_pattern => c_pattern, + p_method => 'GET', + p_source_type => 'mle/javascript', + p_mle_env_name => 'USER_ENV', + p_items_per_page => 0, + p_mimes_allowed => null, + p_comments => null, + p_source => q'~ + (req, resp) => { + const { getAllUsersHandler } = await import ('user_list'); + getAllUsersHandler(req, resp); + } + ~' + ); + commit; +end; +/ + +-------------------------------------------------------------------------------- +-- GET ords/<%= connectionUsername %>/users/:id +-------------------------------------------------------------------------------- +declare + c_module_name constant varchar2(255) := 'users'; + c_pattern constant varchar2(255) := 'users/:id'; +begin + ords.define_template( + p_module_name => c_module_name, + p_pattern => c_pattern + ); + + ords.define_handler( + p_module_name => c_module_name, + p_pattern => c_pattern, + p_method => 'GET', + p_source_type => 'mle/javascript', + p_mle_env_name => 'USER_ENV', + p_items_per_page => 0, + p_mimes_allowed => null, + p_comments => null, + p_source => q'~ + (req, resp) => { + const { getUserHandler } = await import ('user_list'); + getUserHandler(req, resp); + } + ~' + ); + commit; +end; +/ + + +-------------------------------------------------------------------------------- +-- DELETE ords/<%= connectionUsername %>/users/:id +-------------------------------------------------------------------------------- +declare + c_module_name constant varchar2(255) := 'users'; + c_pattern constant varchar2(255) := 'users/:id'; +begin + ords.define_handler( + p_module_name => c_module_name, + p_pattern => c_pattern, + p_method => 'DELETE', + p_source_type => 'mle/javascript', + p_mle_env_name => 'USER_ENV', + p_source => q'~ + (req, resp) => { + const { deleteUserHandler } = await import ('user_list'); + deleteUserHandler(req,resp); + } + ~' + ); + commit; +end; +/ + + +-------------------------------------------------------------------------------- +-- PUT ords/<%= connectionUsername %>/users/:id +-------------------------------------------------------------------------------- +declare + c_module_name constant varchar2(255) := 'users'; + c_pattern constant varchar2(255) := 'users/:id'; +begin + ords.define_handler( + p_module_name => c_module_name, + p_pattern => c_pattern, + p_method => 'PUT', + p_source_type => 'mle/javascript', + p_mle_env_name => 'USER_ENV', + p_source => q'~ + (req, resp) => { + const { updateUserHandler } = await import ('user_list'); + updateUserHandler(req, resp); + } + ~' + ); + commit; +end; +/ \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/utils/database/setup/01-user-setup.sql b/templates/mle-ts-ords-backend/utils/database/setup/01-user-setup.sql new file mode 100644 index 0000000..1b704bc --- /dev/null +++ b/templates/mle-ts-ords-backend/utils/database/setup/01-user-setup.sql @@ -0,0 +1,22 @@ +ALTER SESSION SET CONTAINER = <%= serviceValue %>; + +DECLARE + v_user_count INT; +BEGIN + SELECT COUNT(*) INTO v_user_count + FROM dba_users + WHERE username = UPPER('<%= connectionUsername %>'); + + IF v_user_count = 0 THEN + EXECUTE IMMEDIATE 'CREATE USER <%= connectionUsername %> IDENTIFIED BY "<%= connectionPassword %>"'; + EXECUTE IMMEDIATE 'GRANT CONNECT TO <%= connectionUsername %>'; + EXECUTE IMMEDIATE 'GRANT RESOURCE TO <%= connectionUsername %>'; + EXECUTE IMMEDIATE 'GRANT UNLIMITED TABLESPACE TO <%= connectionUsername %>'; + EXECUTE IMMEDIATE 'GRANT CONNECT, CREATE SESSION, CREATE PROCEDURE, CREATE TABLE TO <%= connectionUsername %>'; + EXECUTE IMMEDIATE 'GRANT EXECUTE ON JAVASCRIPT TO <%= connectionUsername %>'; + EXECUTE IMMEDIATE 'GRANT CREATE MLE TO <%= connectionUsername %>'; + EXECUTE IMMEDIATE 'GRANT CREATE ANY DIRECTORY TO <%= connectionUsername %>'; + EXECUTE IMMEDIATE 'GRANT EXECUTE DYNAMIC MLE TO <%= connectionUsername %>'; + END IF; +END; +/ \ No newline at end of file diff --git a/templates/mle-ts-ords-backend/utils/ords.mjs b/templates/mle-ts-ords-backend/utils/ords.mjs new file mode 100644 index 0000000..74433ff --- /dev/null +++ b/templates/mle-ts-ords-backend/utils/ords.mjs @@ -0,0 +1,30 @@ +import fs from 'fs'; +import path from 'path'; +import { fileURLToPath } from 'url'; +import dotenv from 'dotenv'; +import { execSync } from 'child_process'; + +dotenv.config(); + +const __dirname = path.dirname(fileURLToPath(import.meta.url)); +const sqlPath = path.join(__dirname, 'database/ords.sql'); +const rawSQL = fs.readFileSync(sqlPath, 'utf-8'); + +const moduleName = process.env.MLE_MODULE; + +if (!moduleName) { + console.error('MLE_MODULE is not defined in your .env file'); + process.exit(1); +} + +const replacedSQL = rawSQL.replace(/__MODULE_PLACEHOLDER__/g, moduleName); + +const replacedPath = path.join(__dirname, 'database/ords.processed.sql'); +fs.writeFileSync(replacedPath, replacedSQL); + +console.log(`Replaced placeholder with '${moduleName}' in ${replacedPath}`); + +execSync(`node utils/db.mjs ${replacedPath}`, { stdio: 'inherit' }); + +fs.unlinkSync(replacedPath); +console.log(`Removed temporary file ${replacedPath}`); \ No newline at end of file diff --git a/templates/mle-ts-sample/.env.example.wallet b/templates/mle-ts-sample/.env.example.wallet index 4dc35f5..c6bd847 100644 --- a/templates/mle-ts-sample/.env.example.wallet +++ b/templates/mle-ts-sample/.env.example.wallet @@ -1,6 +1,6 @@ # Path to database wallet WALLET_PATH=<%= walletPath %> - +WALLET_PASSWORD=<%= walletPassword %> # Database User DB_USER=<%= connectionUsername %> # Database User Password diff --git a/templates/mle-ts-sample/deploy.mjs b/templates/mle-ts-sample/deploy.mjs index 44eae7a..da175f4 100644 --- a/templates/mle-ts-sample/deploy.mjs +++ b/templates/mle-ts-sample/deploy.mjs @@ -12,7 +12,7 @@ let moduleName = process.argv[2] || "mleapp"; const tempSqlPath = path.join(os.tmpdir(), `create_module_${Date.now()}.sql`); fs.writeFileSync(tempSqlPath, ` -mle create-module -filename ${bundlePath} -module-name ${moduleName}; +mle create-module -replace -filename ${bundlePath} -module-name ${moduleName}; EXIT; `); diff --git a/templates/mle-ts-sample/src/index.ts b/templates/mle-ts-sample/src/index.ts index 0a9042d..d0f7e86 100644 --- a/templates/mle-ts-sample/src/index.ts +++ b/templates/mle-ts-sample/src/index.ts @@ -1,377 +1 @@ -enum priorities { - LOW = "low", - MEDIUM = "medium", - HIGH = "high", -} - -/** - * Creates a new user in the database with the given name. - * - * Executes an SQL `insert` statement to add a new user to the `users` table. - * The newly created user ID is returned. - * - * @param {string} name - The name of the new user to be added. - * @returns {number} The ID of the newly created user. - */ -export function newUser(name: string): number { - const result = session.execute( - "insert into users (name) values (:name) returning id into :id", - { - name: { - dir: oracledb.BIND_IN, - val: name, - type: oracledb.STRING, - }, - id: { - type: oracledb.NUMBER, - dir: oracledb.BIND_OUT, - }, - }, - ); - const id = result.outBinds.id[0]; - return id; -} - -/** - * Retrieves a user from the database based on the provided user ID. - * - * @param {number} id - The ID of the user to retrieve. - * @returns {any} An object containing the user's ID and name if found, or null if no user is found. - */ -export function getUser(id: number): string | null { - const result = session.execute( - "select id, name from users where id = :id", - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - }, - { outFormat: oracledb.OUT_FORMAT_OBJECT } - ); - - // Return the result as a JSON string so Oracle can handle it - return result.rows?.[0] ? result.rows[0].NAME : null; -} - -/** - * Updates the name of the user with the given ID in the database. - * - * @param {number} id - The ID of the user to be updated. - * @param {string} newName - The new name to be set for the user. - * - * @returns {number} Returns number of rows affected. - */ -export function updateUser(id: number, newName: string) { - const result = session.execute( - "update users set name = :name where id = :id", - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - name: { - dir: oracledb.BIND_IN, - val: newName, - type: oracledb.STRING, - }, - }, - ); - return result.rowsAffected; -} - -/** - * Deletes a user from the database based on the provided user ID. - * - * Executes an SQL `delete` statement to remove the user from the `users` table. - * - * @param {number} id - The ID of the user to delete. - * @returns {number} Returns number of rows affected. - */ -export function deleteUser(id: number) { - const result = session.execute( - "delete from users where id = :id", - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - }, - ); - return result.rowsAffected; -} - -/** - * Creates a new category in the database with the given name and priority. - * - * Executes an SQL `insert` statement to add a new category to the `categories` table. - * The newly created category ID is returned. - * - * @param {string} name - The name of the new category to be added. - * @param {priorities} priority - The priority level of the new category. It can be one of `priorities.LOW`, `priorities.MEDIUM`, or `priorities.HIGH`. - * @returns {number} The ID of the newly created category. - */ -export function newCategory(name: string, priority: priorities): number { - const result = session.execute( - "insert into categories (name, prio) values (:name, :prio) returning id into :id", - { - name: { - dir: oracledb.BIND_IN, - val: name, - type: oracledb.STRING, - }, - prio: { - dir: oracledb.BIND_IN, - val: priority, - type: oracledb.STRING, - }, - id: { - type: oracledb.NUMBER, - dir: oracledb.BIND_OUT, - }, - }, - ); - - const id = result.outBinds.id[0]; - - return id; -} - -/** - * Retrieves a category from the database based on the provided category ID. - * - * Executes an SQL `select` statement to fetch the category details from the `categories` table. - * - * @param {number} id - The ID of the category to retrieve. - * @returns {any} An object containing the category's ID, name, and priority if found, or null if no category is found. - */ -export function getCategory(id: number) { - const result = session.execute( - "select id, name, prio from categories where id = :id", - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - }, - { outFormat: oracledb.OUT_FORMAT_OBJECT } - ); - - return result.rows?.[0] || null; -} - -/** - * Updates the name and priority of the category with the given ID in the database. - * - * Executes an SQL `update` statement to modify the category's details in the `categories` table. - * - * @param {number} id - The ID of the category to be updated. - * @param {string} newName - The new name to be set for the category. - * @param {priorities} newPriority - The new priority level to be set for the category. It can be one of `priorities.LOW`, `priorities.MEDIUM`, or `priorities.HIGH`. - * @returns {number} Returns number of rows affected. - */ -export function updateCategory(id: number, newName: string, newPriority: priorities) { - const result = session.execute( - "update categories set name = :name, prio = :prio where id = :id", - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - name: { - dir: oracledb.BIND_IN, - val: newName, - type: oracledb.STRING, - }, - prio: { - dir: oracledb.BIND_IN, - val: newPriority, - type: oracledb.STRING, - }, - }, - ); - - return result.rowsAffected; -} - -/** - * Deletes a category from the database based on the provided category ID. - * - * Executes an SQL `delete` statement to remove the category from the `categories` table. - * - * @param {number} id - The ID of the category to delete. - * @returns {number} Returns number of rows affected. - */ -export function deleteCategory(id: number) { - const result = session.execute( - "delete from categories where id = :id", - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - }, - ); - - return result.rowsAffected; -} - -/** - * Creates a new to-do item in the database with the given user ID, category ID, name, and completion status. - * - * Executes an SQL `insert` statement to add a new to-do item to the `todo_list` table. - * The newly created to-do item ID is returned. - * - * @param {number} userId - The ID of the user associated with the to-do item. - * @param {number} categoryId - The ID of the category associated with the to-do item. - * @param {string} name - The name of the to-do item. - * @param {boolean} [completed=false] - The completion status of the to-do item. Defaults to `false`. - * @returns {number} The ID of the newly created to-do item. - */ -export function newTodoItem(userId: number, categoryId: number, name: string, completed: boolean = false): number { - const result = session.execute( - `insert into todo_list (u_id, c_id, name, completed) - values (:u_id, :c_id, :name, :completed) - returning id into :id`, - { - u_id: { - dir: oracledb.BIND_IN, - val: userId, - type: oracledb.NUMBER, - }, - c_id: { - dir: oracledb.BIND_IN, - val: categoryId, - type: oracledb.NUMBER, - }, - name: { - dir: oracledb.BIND_IN, - val: name, - type: oracledb.STRING, - }, - completed: { - dir: oracledb.BIND_IN, - val: completed ? 1 : 0, - type: oracledb.NUMBER, - }, - id: { - type: oracledb.NUMBER, - dir: oracledb.BIND_OUT, - }, - } - ); - - const id = result.outBinds.id[0]; - return id; -} - -/** - * Retrieves a to-do item from the database based on the provided to-do item ID. - * - * Executes an SQL `select` statement to fetch the to-do item details from the `todo_list` table. - * - * @param {number} id - The ID of the to-do item to retrieve. - * @returns {any} An object containing the to-do item's ID, user ID (u_id), category ID (c_id), name, and completion status (completed) if found, or null if no to-do item is found. - */ -export function getTodoItem(id: number) { - const result = session.execute( - `select id, u_id, c_id, name, completed from todo_list where id = :id`, - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - }, - { outFormat: oracledb.OUT_FORMAT_OBJECT } - ); - - return result.rows?.[0] || null; -} - -/** - * Updates the name and completion status of the to-do item with the given ID in the database. - * - * Executes an SQL `update` statement to modify the to-do item's details in the `todo_list` table. - * - * @param {number} id - The ID of the to-do item to be updated. - * @param {string} newName - The new name to be set for the to-do item. - * @param {boolean} newCompleted - The new completion status to be set for the to-do item. - * @returns {number} Returns number of rows affected. - */ -export function updateTodoItem(id: number, newName: string, newCompleted: boolean) { - const result = session.execute( - `update todo_list set name = :name, completed = :completed where id = :id`, - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - name: { - dir: oracledb.BIND_IN, - val: newName, - type: oracledb.STRING, - }, - completed: { - dir: oracledb.BIND_IN, - val: newCompleted ? 1 : 0, - type: oracledb.NUMBER, - }, - } - ); - - return result.rowsAffected; -} - -/** - * Deletes a to-do item from the database based on the provided to-do item ID. - * - * Executes an SQL `delete` statement to remove the to-do item from the `todo_list` table. - * - * @param {number} id - The ID of the to-do item to delete. - * @returns {number} Returns number of rows affected. - */ -export function deleteTodoItem(id: number) { - const result = session.execute( - "delete from todo_list where id = :id", - { - id: { - dir: oracledb.BIND_IN, - val: id, - type: oracledb.NUMBER, - }, - } - ); - - return result.rowsAffected; -} - -/** - * Retrieves all to-do items for the given user ID from the database. - * - * Executes an SQL `select` statement to fetch all to-do items associated with the specified user from the `todo_list` table. - * - * @param {number} userId - The ID of the user whose to-do items are to be retrieved. - * @returns {any[]} An array of objects, each containing the to-do item's ID, category ID (c_id), name, and completion status (completed). - */ -export function getTodosByUser(userId: number) { - const result = session.execute( - "select id, c_id, name, completed from todo_list where u_id = :u_id", - { - u_id: { - dir: oracledb.BIND_IN, - val: userId, - type: oracledb.NUMBER, - }, - }, - { outFormat: oracledb.OUT_FORMAT_OBJECT } - ); - return result.rows || []; -} \ No newline at end of file +export {newUser, getUser, getAllUsers, updateUser, deleteUser, newCategory, getCategory, updateCategory, deleteCategory, newTodoItem, getTodosByUser, getTodoItem, updateTodoItem, deleteTodoItem} from './todos'; \ No newline at end of file diff --git a/templates/mle-ts-sample/src/todos.ts b/templates/mle-ts-sample/src/todos.ts new file mode 100644 index 0000000..3965657 --- /dev/null +++ b/templates/mle-ts-sample/src/todos.ts @@ -0,0 +1,392 @@ +enum priorities { + LOW = "low", + MEDIUM = "medium", + HIGH = "high", +} + +/** + * Creates a new user in the database with the given name. + * + * Executes an SQL `insert` statement to add a new user to the `users` table. + * The newly created user ID is returned. + * + * @param {string} name - The name of the new user to be added. + * @returns {number} The ID of the newly created user. + */ +export function newUser(name: string): number { + const result = session.execute( + "insert into users (name) values (:name) returning id into :id", + { + name: { + dir: oracledb.BIND_IN, + val: name, + type: oracledb.STRING, + }, + id: { + type: oracledb.NUMBER, + dir: oracledb.BIND_OUT, + }, + }, + ); + const id = result?.outBinds?.id?.[0]; + return id; +} + +/** + * Retrieves a user from the database based on the provided user ID. + * + * @param {number} id - The ID of the user to retrieve. + * @returns {any} An object containing the user's ID and name if found, or null if no user is found. + */ +export function getUser(id: number): string | null { + const result = session.execute( + "select id, name from users where id = :id", + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + }, + { outFormat: oracledb.OUT_FORMAT_OBJECT } + ); + + // Return the result as a JSON string so Oracle can handle it + return result.rows?.[0] ? result.rows[0].NAME : null; +} + +/** + * Retrieves all users from the database. + * + * @returns {any[]} An array of objects, each containing a user's ID and name. + */ +export function getAllUsers(): any[] { + const result = session.execute( + "select id, name from users", + {}, + { outFormat: oracledb.OUT_FORMAT_OBJECT } + ); + // Return all rows as an array of { id, name } objects + return result.rows || []; +} + +/** + * Updates the name of the user with the given ID in the database. + * + * @param {number} id - The ID of the user to be updated. + * @param {string} newName - The new name to be set for the user. + * + * @returns {number} Returns number of rows affected. + */ +export function updateUser(id: number, newName: string) { + const result = session.execute( + "update users set name = :name where id = :id", + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + name: { + dir: oracledb.BIND_IN, + val: newName, + type: oracledb.STRING, + }, + }, + ); + return result.rowsAffected; +} + +/** + * Deletes a user from the database based on the provided user ID. + * + * Executes an SQL `delete` statement to remove the user from the `users` table. + * + * @param {number} id - The ID of the user to delete. + * @returns {number} Returns number of rows affected. + */ +export function deleteUser(id: number) { + const result = session.execute( + "delete from users where id = :id", + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + }, + ); + return result.rowsAffected; +} + +/** + * Creates a new category in the database with the given name and priority. + * + * Executes an SQL `insert` statement to add a new category to the `categories` table. + * The newly created category ID is returned. + * + * @param {string} name - The name of the new category to be added. + * @param {priorities} priority - The priority level of the new category. It can be one of `priorities.LOW`, `priorities.MEDIUM`, or `priorities.HIGH`. + * @returns {number} The ID of the newly created category. + */ +export function newCategory(name: string, priority: priorities): number { + const result = session.execute( + "insert into categories (name, prio) values (:name, :prio) returning id into :id", + { + name: { + dir: oracledb.BIND_IN, + val: name, + type: oracledb.STRING, + }, + prio: { + dir: oracledb.BIND_IN, + val: priority, + type: oracledb.STRING, + }, + id: { + type: oracledb.NUMBER, + dir: oracledb.BIND_OUT, + }, + }, + ); + + const id = result?.outBinds?.id?.[0]; + + return id; +} + +/** + * Retrieves a category from the database based on the provided category ID. + * + * Executes an SQL `select` statement to fetch the category details from the `categories` table. + * + * @param {number} id - The ID of the category to retrieve. + * @returns {any} An object containing the category's ID, name, and priority if found, or null if no category is found. + */ +export function getCategory(id: number) { + const result = session.execute( + "select id, name, prio from categories where id = :id", + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + }, + { outFormat: oracledb.OUT_FORMAT_OBJECT } + ); + + return result.rows?.[0] || null; +} + +/** + * Updates the name and priority of the category with the given ID in the database. + * + * Executes an SQL `update` statement to modify the category's details in the `categories` table. + * + * @param {number} id - The ID of the category to be updated. + * @param {string} newName - The new name to be set for the category. + * @param {priorities} newPriority - The new priority level to be set for the category. It can be one of `priorities.LOW`, `priorities.MEDIUM`, or `priorities.HIGH`. + * @returns {number} Returns number of rows affected. + */ +export function updateCategory(id: number, newName: string, newPriority: priorities) { + const result = session.execute( + "update categories set name = :name, prio = :prio where id = :id", + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + name: { + dir: oracledb.BIND_IN, + val: newName, + type: oracledb.STRING, + }, + prio: { + dir: oracledb.BIND_IN, + val: newPriority, + type: oracledb.STRING, + }, + }, + ); + + return result.rowsAffected; +} + +/** + * Deletes a category from the database based on the provided category ID. + * + * Executes an SQL `delete` statement to remove the category from the `categories` table. + * + * @param {number} id - The ID of the category to delete. + * @returns {number} Returns number of rows affected. + */ +export function deleteCategory(id: number) { + const result = session.execute( + "delete from categories where id = :id", + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + }, + ); + + return result.rowsAffected; +} + +/** + * Creates a new to-do item in the database with the given user ID, category ID, name, and completion status. + * + * Executes an SQL `insert` statement to add a new to-do item to the `todo_list` table. + * The newly created to-do item ID is returned. + * + * @param {number} userId - The ID of the user associated with the to-do item. + * @param {number} categoryId - The ID of the category associated with the to-do item. + * @param {string} name - The name of the to-do item. + * @param {boolean} [completed=false] - The completion status of the to-do item. Defaults to `false`. + * @returns {number} The ID of the newly created to-do item. + */ +export function newTodoItem(userId: number, categoryId: number, name: string, completed: boolean = false): number { + const result = session.execute( + `insert into todo_list (u_id, c_id, name, completed) + values (:u_id, :c_id, :name, :completed) + returning id into :id`, + { + u_id: { + dir: oracledb.BIND_IN, + val: userId, + type: oracledb.NUMBER, + }, + c_id: { + dir: oracledb.BIND_IN, + val: categoryId, + type: oracledb.NUMBER, + }, + name: { + dir: oracledb.BIND_IN, + val: name, + type: oracledb.STRING, + }, + completed: { + dir: oracledb.BIND_IN, + val: completed ? 1 : 0, + type: oracledb.NUMBER, + }, + id: { + type: oracledb.NUMBER, + dir: oracledb.BIND_OUT, + }, + } + ); + + const id = result?.outBinds?.id?.[0]; + return id; +} + +/** + * Retrieves a to-do item from the database based on the provided to-do item ID. + * + * Executes an SQL `select` statement to fetch the to-do item details from the `todo_list` table. + * + * @param {number} id - The ID of the to-do item to retrieve. + * @returns {any} An object containing the to-do item's ID, user ID (u_id), category ID (c_id), name, and completion status (completed) if found, or null if no to-do item is found. + */ +export function getTodoItem(id: number) { + const result = session.execute( + `select id, u_id, c_id, name, completed from todo_list where id = :id`, + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + }, + { outFormat: oracledb.OUT_FORMAT_OBJECT } + ); + + return result.rows?.[0] || null; +} + +/** + * Updates the name and completion status of the to-do item with the given ID in the database. + * + * Executes an SQL `update` statement to modify the to-do item's details in the `todo_list` table. + * + * @param {number} id - The ID of the to-do item to be updated. + * @param {string} newName - The new name to be set for the to-do item. + * @param {boolean} newCompleted - The new completion status to be set for the to-do item. + * @returns {number} Returns number of rows affected. + */ +export function updateTodoItem(id: number, newName: string, newCompleted: boolean) { + const result = session.execute( + `update todo_list set name = :name, completed = :completed where id = :id`, + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + name: { + dir: oracledb.BIND_IN, + val: newName, + type: oracledb.STRING, + }, + completed: { + dir: oracledb.BIND_IN, + val: newCompleted ? 1 : 0, + type: oracledb.NUMBER, + }, + } + ); + + return result.rowsAffected; +} + +/** + * Deletes a to-do item from the database based on the provided to-do item ID. + * + * Executes an SQL `delete` statement to remove the to-do item from the `todo_list` table. + * + * @param {number} id - The ID of the to-do item to delete. + * @returns {number} Returns number of rows affected. + */ +export function deleteTodoItem(id: number) { + const result = session.execute( + "delete from todo_list where id = :id", + { + id: { + dir: oracledb.BIND_IN, + val: id, + type: oracledb.NUMBER, + }, + } + ); + + return result.rowsAffected; +} + +/** + * Retrieves all to-do items for the given user ID from the database. + * + * Executes an SQL `select` statement to fetch all to-do items associated with the specified user from the `todo_list` table. + * + * @param {number} userId - The ID of the user whose to-do items are to be retrieved. + * @returns {any[]} An array of objects, each containing the to-do item's ID, category ID (c_id), name, and completion status (completed). + */ +export function getTodosByUser(userId: number) { + const result = session.execute( + "select id, c_id, name, completed from todo_list where u_id = :u_id", + { + u_id: { + dir: oracledb.BIND_IN, + val: userId, + type: oracledb.NUMBER, + }, + }, + { outFormat: oracledb.OUT_FORMAT_OBJECT } + ); + return result.rows || []; +} \ No newline at end of file diff --git a/templates/mle-ts-sample/test/users.test.js b/templates/mle-ts-sample/test/users.test.js index f2647bd..56b3a50 100644 --- a/templates/mle-ts-sample/test/users.test.js +++ b/templates/mle-ts-sample/test/users.test.js @@ -1,13 +1,25 @@ import dotenv from 'dotenv'; import oracledb from 'oracledb'; import { beforeAll, afterAll, describe, it, expect } from 'vitest'; +import path from "path"; dotenv.config(); -const dbConfig = { +let walletPath = process.env.WALLET_PATH; +let walletPassword = process.env.WALLET_PASSWORD; +if(walletPath && walletPath.length>0) { + walletPath = path.join(process.cwd(), path.normalize('./server/utils/db/wallet')); +} + +const dbConfig = { user: process.env.DB_USER, password: process.env.DB_PASSWORD, connectString: process.env.CONNECT_STRING, + ...(walletPath && walletPath.length > 0 ? { + configDir: walletPath, + walletLocation: walletPath, + walletPassword: walletPassword + }:{}) }; let mleModuleName = process.env.MLE_MODULE; @@ -41,6 +53,7 @@ const createPackageSQL = ` CREATE OR REPLACE PACKAGE user_package AS FUNCTION newUserFunc(name IN VARCHAR2) RETURN NUMBER; FUNCTION getUser(id IN NUMBER) RETURN VARCHAR2; + FUNCTION getAllUsers RETURN JSON; FUNCTION updateUser(id IN NUMBER, name IN VARCHAR2) RETURN NUMBER; FUNCTION deleteUser(id IN NUMBER) RETURN NUMBER; END user_package; @@ -56,6 +69,10 @@ CREATE OR REPLACE PACKAGE BODY user_package AS AS MLE MODULE ${mleModuleName} SIGNATURE 'getUser(number)'; + FUNCTION getAllUsers RETURN JSON + AS MLE MODULE ${mleModuleName} + SIGNATURE 'getAllUsers()'; + FUNCTION updateUser(id IN NUMBER, name IN VARCHAR2) RETURN NUMBER AS MLE MODULE ${mleModuleName} SIGNATURE 'updateUser(number, string)'; @@ -146,6 +163,41 @@ describe('user_package', () => { expect(result.outBinds.user).toBe('John Doe'); }); + it('should get all users', async () => { + // First create two users + const binds1 = { + name: 'Alice', + id: { dir: oracledb.BIND_OUT, type: oracledb.NUMBER } + }; + const r1 = await executeSQLScriptWithOutput( + `BEGIN :id := USER_PACKAGE.NEWUSERFUNC(:name); END;`, + binds1 + ); + + const binds2 = { + name: 'Bob', + id: { dir: oracledb.BIND_OUT, type: oracledb.NUMBER } + }; + const r2 = await executeSQLScriptWithOutput( + `BEGIN :id := USER_PACKAGE.NEWUSERFUNC(:name); END;`, + binds2 + ); + + const plsql = `BEGIN :json := USER_PACKAGE.GETALLUSERS(); END;`; + const binds = { + json: { dir: oracledb.BIND_OUT, type: oracledb.DB_TYPE_JSON } + }; + + const result = await executeSQLScriptWithOutput(plsql, binds); + const items = result.outBinds.json; + + expect(Array.isArray(items)).toBe(true); + // // Expect at least the two recently created users + const names = items.map(u => u.NAME); + expect(names).toContain('Alice'); + expect(names).toContain('Bob'); + }); + it('should update a user by ID', async () => { const plsql = `BEGIN :affected := USER_PACKAGE.UPDATEUSER(:id, :name); END;`; const binds = { id: createdUserId,