UNPKG

defarm-sdk

Version:

DeFarm SDK - On-premise blockchain data processing and tokenization engine for agriculture supply chain

464 lines (401 loc) 15 kB
import type { StorageAdapter, Asset, Transaction } from '../types'; export interface OracleConfig { user: string; password: string; connectString: string; poolMin?: number; poolMax?: number; poolIncrement?: number; poolTimeout?: number; connectionTimeout?: number; stmtCacheSize?: number; } interface OracleConnection { execute(sql: string, binds?: any[], options?: any): Promise<any>; commit(): Promise<void>; rollback(): Promise<void>; close(): Promise<void>; } interface OraclePool { getConnection(): Promise<OracleConnection>; close(drainTime?: number): Promise<void>; } export class OracleAdapter implements StorageAdapter { private oracledb: any = null; private pool: OraclePool | null = null; private config: OracleConfig; constructor(config: OracleConfig) { this.config = { poolMin: 2, poolMax: 10, poolIncrement: 1, poolTimeout: 60, connectionTimeout: 60, stmtCacheSize: 30, ...config }; } async connect(): Promise<void> { if (this.pool) { return; } try { this.oracledb = require('oracledb'); this.oracledb.outFormat = this.oracledb.OUT_FORMAT_OBJECT; this.oracledb.autoCommit = false; this.pool = await this.oracledb.createPool({ user: this.config.user, password: this.config.password, connectString: this.config.connectString, poolMin: this.config.poolMin, poolMax: this.config.poolMax, poolIncrement: this.config.poolIncrement, poolTimeout: this.config.poolTimeout, stmtCacheSize: this.config.stmtCacheSize }); const connection = await this.pool.getConnection(); await connection.close(); await this.ensureTablesExist(); } catch (error) { throw new Error(`Failed to connect to Oracle: ${error instanceof Error ? error.message : 'Unknown error'}`); } } async disconnect(): Promise<void> { if (this.pool) { await this.pool.close(10); this.pool = null; } } async saveAsset(asset: Asset): Promise<string> { this.assertConnected(); const connection = await this.pool!.getConnection(); try { const assetId = asset.id || this.generateId(); const sql = ` MERGE INTO defarm_assets target USING (SELECT :id as id FROM dual) source ON (target.id = source.id) WHEN MATCHED THEN UPDATE SET dfid = :dfid, name = :name, category = :category, subcategory = :subcategory, owner_id = :owner_id, owner_name = :owner_name, location_country = :location_country, location_state = :location_state, location_municipality = :location_municipality, location_coordinates = :location_coordinates, asset_data = :asset_data, metadata_source = :metadata_source, metadata_from_producer = :metadata_from_producer, metadata_visibility = :metadata_visibility, metadata_updated = SYSTIMESTAMP, metadata_version = :metadata_version WHEN NOT MATCHED THEN INSERT ( id, dfid, name, category, subcategory, owner_id, owner_name, location_country, location_state, location_municipality, location_coordinates, asset_data, metadata_source, metadata_from_producer, metadata_visibility, metadata_created, metadata_updated, metadata_version ) VALUES ( :id, :dfid, :name, :category, :subcategory, :owner_id, :owner_name, :location_country, :location_state, :location_municipality, :location_coordinates, :asset_data, :metadata_source, :metadata_from_producer, :metadata_visibility, SYSTIMESTAMP, SYSTIMESTAMP, :metadata_version ) `; const binds = { id: assetId, dfid: asset.dfid, name: asset.name, category: asset.category, subcategory: asset.subcategory, owner_id: asset.ownership.ownerId, owner_name: asset.ownership.ownerName, location_country: asset.ownership.location?.country, location_state: asset.ownership.location?.state, location_municipality: asset.ownership.location?.municipality, location_coordinates: asset.ownership.location?.coordinates ? JSON.stringify(asset.ownership.location.coordinates) : null, asset_data: JSON.stringify(asset.data), metadata_source: asset.metadata.source, metadata_from_producer: asset.metadata.fromProducer ? 1 : 0, metadata_visibility: asset.metadata.visibility, metadata_version: asset.metadata.version }; await connection.execute(sql, binds); await connection.commit(); return assetId; } finally { await connection.close(); } } async getAsset(id: string): Promise<Asset | null> { this.assertConnected(); const connection = await this.pool!.getConnection(); try { const sql = `SELECT * FROM defarm_assets WHERE id = :id`; const result = await connection.execute(sql, { id }); if (!result.rows || result.rows.length === 0) { return null; } return this.mapRowToAsset(result.rows[0]); } finally { await connection.close(); } } async queryAssets(filters?: { category?: string; ownerId?: string; country?: string; fromProducer?: boolean; visibility?: string; limit?: number; offset?: number; }): Promise<Asset[]> { this.assertConnected(); const connection = await this.pool!.getConnection(); try { let sql = 'SELECT * FROM defarm_assets WHERE 1=1'; const binds: any = {}; if (filters?.category) { sql += ' AND category = :category'; binds.category = filters.category; } if (filters?.ownerId) { sql += ' AND owner_id = :owner_id'; binds.owner_id = filters.ownerId; } if (filters?.country) { sql += ' AND location_country = :country'; binds.country = filters.country; } if (filters?.fromProducer !== undefined) { sql += ' AND metadata_from_producer = :from_producer'; binds.from_producer = filters.fromProducer ? 1 : 0; } if (filters?.visibility) { sql += ' AND metadata_visibility = :visibility'; binds.visibility = filters.visibility; } sql += ' ORDER BY metadata_created DESC'; if (filters?.limit) { if (filters?.offset) { sql = `SELECT * FROM (SELECT a.*, ROWNUM rnum FROM (${sql}) a WHERE ROWNUM <= :max_row) WHERE rnum > :min_row`; binds.max_row = (filters.offset || 0) + filters.limit; binds.min_row = filters.offset || 0; } else { sql = `SELECT * FROM (${sql}) WHERE ROWNUM <= :limit`; binds.limit = filters.limit; } } const result = await connection.execute(sql, binds); return (result.rows || []).map((row: any) => this.mapRowToAsset(row)); } finally { await connection.close(); } } async saveAssetsBatch(assets: Asset[]): Promise<string[]> { this.assertConnected(); const connection = await this.pool!.getConnection(); try { const ids: string[] = []; for (const asset of assets) { const id = await this.saveAssetInTransaction(connection, asset); ids.push(id); } await connection.commit(); return ids; } catch (error) { await connection.rollback(); throw error; } finally { await connection.close(); } } async beginTransaction(): Promise<Transaction> { this.assertConnected(); const connection = await this.pool!.getConnection(); return { async commit() { try { await connection.commit(); } finally { await connection.close(); } }, async rollback() { try { await connection.rollback(); } finally { await connection.close(); } } }; } private async ensureTablesExist(): Promise<void> { const connection = await this.pool!.getConnection(); try { const checkTableSql = ` SELECT COUNT(*) as count FROM user_tables WHERE table_name = 'DEFARM_ASSETS' `; const result = await connection.execute(checkTableSql); const tableExists = result.rows && result.rows[0] && result.rows[0].COUNT > 0; if (!tableExists) { const createTableSql = ` CREATE TABLE defarm_assets ( id VARCHAR2(255) PRIMARY KEY, dfid VARCHAR2(255) UNIQUE, name VARCHAR2(500) NOT NULL, category VARCHAR2(50) NOT NULL, subcategory VARCHAR2(100) NOT NULL, -- Ownership information owner_id VARCHAR2(255) NOT NULL, owner_name VARCHAR2(500) NOT NULL, location_country VARCHAR2(100), location_state VARCHAR2(100), location_municipality VARCHAR2(200), location_coordinates CLOB CHECK (location_coordinates IS JSON), -- Asset-specific data (flexible JSON) asset_data CLOB CHECK (asset_data IS JSON) NOT NULL, -- Metadata metadata_source VARCHAR2(50) NOT NULL CHECK (metadata_source IN ('producer', 'authority', 'enterprise', 'association')), metadata_from_producer NUMBER(1) DEFAULT 0 CHECK (metadata_from_producer IN (0, 1)), metadata_visibility VARCHAR2(20) NOT NULL CHECK (metadata_visibility IN ('public', 'private', 'partners')), metadata_created TIMESTAMP WITH TIME ZONE DEFAULT SYSTIMESTAMP, metadata_updated TIMESTAMP WITH TIME ZONE DEFAULT SYSTIMESTAMP, metadata_version NUMBER DEFAULT 1 ) `; await connection.execute(createTableSql); const indexes = [ 'CREATE INDEX idx_defarm_assets_category ON defarm_assets(category)', 'CREATE INDEX idx_defarm_assets_owner_id ON defarm_assets(owner_id)', 'CREATE INDEX idx_defarm_assets_country ON defarm_assets(location_country)', 'CREATE INDEX idx_defarm_assets_from_producer ON defarm_assets(metadata_from_producer)', 'CREATE INDEX idx_defarm_assets_visibility ON defarm_assets(metadata_visibility)', 'CREATE INDEX idx_defarm_assets_created ON defarm_assets(metadata_created)', 'CREATE INDEX idx_defarm_assets_dfid ON defarm_assets(dfid)' ]; for (const indexSql of indexes) { try { await connection.execute(indexSql); } catch (error) { console.warn(`Failed to create index: ${error}`); } } const triggerSql = ` CREATE OR REPLACE TRIGGER trg_defarm_assets_updated BEFORE UPDATE ON defarm_assets FOR EACH ROW BEGIN :NEW.metadata_updated := SYSTIMESTAMP; END; `; await connection.execute(triggerSql); await connection.commit(); } } finally { await connection.close(); } } private async saveAssetInTransaction(connection: OracleConnection, asset: Asset): Promise<string> { const assetId = asset.id || this.generateId(); const sql = ` MERGE INTO defarm_assets target USING (SELECT :id as id FROM dual) source ON (target.id = source.id) WHEN MATCHED THEN UPDATE SET dfid = :dfid, name = :name, category = :category, subcategory = :subcategory, owner_id = :owner_id, owner_name = :owner_name, location_country = :location_country, location_state = :location_state, location_municipality = :location_municipality, location_coordinates = :location_coordinates, asset_data = :asset_data, metadata_source = :metadata_source, metadata_from_producer = :metadata_from_producer, metadata_visibility = :metadata_visibility, metadata_updated = SYSTIMESTAMP, metadata_version = :metadata_version WHEN NOT MATCHED THEN INSERT ( id, dfid, name, category, subcategory, owner_id, owner_name, location_country, location_state, location_municipality, location_coordinates, asset_data, metadata_source, metadata_from_producer, metadata_visibility, metadata_created, metadata_updated, metadata_version ) VALUES ( :id, :dfid, :name, :category, :subcategory, :owner_id, :owner_name, :location_country, :location_state, :location_municipality, :location_coordinates, :asset_data, :metadata_source, :metadata_from_producer, :metadata_visibility, SYSTIMESTAMP, SYSTIMESTAMP, :metadata_version ) `; const binds = { id: assetId, dfid: asset.dfid, name: asset.name, category: asset.category, subcategory: asset.subcategory, owner_id: asset.ownership.ownerId, owner_name: asset.ownership.ownerName, location_country: asset.ownership.location?.country, location_state: asset.ownership.location?.state, location_municipality: asset.ownership.location?.municipality, location_coordinates: asset.ownership.location?.coordinates ? JSON.stringify(asset.ownership.location.coordinates) : null, asset_data: JSON.stringify(asset.data), metadata_source: asset.metadata.source, metadata_from_producer: asset.metadata.fromProducer ? 1 : 0, metadata_visibility: asset.metadata.visibility, metadata_version: asset.metadata.version }; await connection.execute(sql, binds); return assetId; } private mapRowToAsset(row: any): Asset { return { id: row.ID, dfid: row.DFID, name: row.NAME, category: row.CATEGORY, subcategory: row.SUBCATEGORY, ownership: { ownerId: row.OWNER_ID, ownerName: row.OWNER_NAME, location: { country: row.LOCATION_COUNTRY, state: row.LOCATION_STATE, municipality: row.LOCATION_MUNICIPALITY, coordinates: row.LOCATION_COORDINATES ? JSON.parse(row.LOCATION_COORDINATES) : undefined } }, data: JSON.parse(row.ASSET_DATA), metadata: { source: row.METADATA_SOURCE, fromProducer: row.METADATA_FROM_PRODUCER === 1, visibility: row.METADATA_VISIBILITY, created: row.METADATA_CREATED, updated: row.METADATA_UPDATED, version: row.METADATA_VERSION } }; } private assertConnected(): void { if (!this.pool) { throw new Error('Oracle adapter not connected. Call connect() first.'); } } private generateId(): string { return `ora_${Date.now()}_${Math.random().toString(36).substring(7)}`; } }