defarm-sdk
Version:
DeFarm SDK - On-premise blockchain data processing and tokenization engine for agriculture supply chain
489 lines (420 loc) • 16.8 kB
text/typescript
import type { StorageAdapter, Asset, Transaction } from '../types';
export interface SQLServerConfig {
server: string;
port?: number;
database: string;
user: string;
password: string;
domain?: string;
instanceName?: string;
encrypt?: boolean;
trustServerCertificate?: boolean;
connectionTimeout?: number;
requestTimeout?: number;
pool?: {
max?: number;
min?: number;
idleTimeoutMillis?: number;
acquireTimeoutMillis?: number;
};
}
interface SQLServerConnection {
request(): any;
beginTransaction(): Promise<any>;
close(): Promise<void>;
}
interface SQLServerConnectionPool {
connect(): Promise<SQLServerConnection>;
close(): Promise<void>;
}
export class SQLServerAdapter implements StorageAdapter {
private sql: any = null;
private pool: SQLServerConnectionPool | null = null;
private config: SQLServerConfig;
constructor(config: SQLServerConfig) {
this.config = {
port: 1433,
encrypt: true,
trustServerCertificate: false,
connectionTimeout: 15000,
requestTimeout: 15000,
pool: {
max: 10,
min: 0,
idleTimeoutMillis: 30000,
acquireTimeoutMillis: 60000
},
...config
};
}
async connect(): Promise<void> {
if (this.pool) {
return;
}
try {
this.sql = require('mssql');
const poolConfig = {
server: this.config.server,
port: this.config.port,
database: this.config.database,
user: this.config.user,
password: this.config.password,
domain: this.config.domain,
instanceName: this.config.instanceName,
options: {
encrypt: this.config.encrypt,
trustServerCertificate: this.config.trustServerCertificate
},
connectionTimeout: this.config.connectionTimeout,
requestTimeout: this.config.requestTimeout,
pool: this.config.pool
};
this.pool = new this.sql.ConnectionPool(poolConfig);
await this.pool.connect();
await this.ensureTablesExist();
} catch (error) {
throw new Error(`Failed to connect to SQL Server: ${error instanceof Error ? error.message : 'Unknown error'}`);
}
}
async disconnect(): Promise<void> {
if (this.pool) {
await this.pool.close();
this.pool = null;
}
}
async saveAsset(asset: Asset): Promise<string> {
this.assertConnected();
const request = this.pool!.request();
try {
const assetId = asset.id || this.generateId();
const sql = `
MERGE defarm_assets AS target
USING (SELECT AS id) AS source
ON target.id = source.id
WHEN MATCHED THEN
UPDATE SET
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_updated = GETUTCDATE(),
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 (
, , , , ,
, , , ,
, ,
, , ,
, GETUTCDATE(), GETUTCDATE(),
);
`;
request.input('id', this.sql.VarChar(255), assetId);
request.input('dfid', this.sql.VarChar(255), asset.dfid);
request.input('name', this.sql.NVarChar(500), asset.name);
request.input('category', this.sql.VarChar(50), asset.category);
request.input('subcategory', this.sql.VarChar(100), asset.subcategory);
request.input('owner_id', this.sql.VarChar(255), asset.ownership.ownerId);
request.input('owner_name', this.sql.NVarChar(500), asset.ownership.ownerName);
request.input('location_country', this.sql.VarChar(100), asset.ownership.location?.country);
request.input('location_state', this.sql.VarChar(100), asset.ownership.location?.state);
request.input('location_municipality', this.sql.NVarChar(200), asset.ownership.location?.municipality);
request.input('location_coordinates', this.sql.NVarChar(this.sql.MAX),
asset.ownership.location?.coordinates ? JSON.stringify(asset.ownership.location.coordinates) : null);
request.input('asset_data', this.sql.NVarChar(this.sql.MAX), JSON.stringify(asset.data));
request.input('metadata_source', this.sql.VarChar(50), asset.metadata.source);
request.input('metadata_from_producer', this.sql.Bit, asset.metadata.fromProducer);
request.input('metadata_visibility', this.sql.VarChar(20), asset.metadata.visibility);
request.input('metadata_version', this.sql.Int, asset.metadata.version);
await request.query(sql);
return assetId;
} catch (error) {
throw error;
}
}
async getAsset(id: string): Promise<Asset | null> {
this.assertConnected();
const request = this.pool!.request();
try {
const sql = `SELECT * FROM defarm_assets WHERE id = `;
request.input('id', this.sql.VarChar(255), id);
const result = await request.query(sql);
if (!result.recordset || result.recordset.length === 0) {
return null;
}
return this.mapRowToAsset(result.recordset[0]);
} catch (error) {
throw error;
}
}
async queryAssets(filters?: {
category?: string;
ownerId?: string;
country?: string;
fromProducer?: boolean;
visibility?: string;
limit?: number;
offset?: number;
}): Promise<Asset[]> {
this.assertConnected();
const request = this.pool!.request();
try {
let sql = 'SELECT * FROM defarm_assets WHERE 1=1';
const conditions: string[] = [];
if (filters?.category) {
conditions.push('category = @category');
request.input('category', this.sql.VarChar(50), filters.category);
}
if (filters?.ownerId) {
conditions.push('owner_id = @owner_id');
request.input('owner_id', this.sql.VarChar(255), filters.ownerId);
}
if (filters?.country) {
conditions.push('location_country = @country');
request.input('country', this.sql.VarChar(100), filters.country);
}
if (filters?.fromProducer !== undefined) {
conditions.push('metadata_from_producer = @from_producer');
request.input('from_producer', this.sql.Bit, filters.fromProducer);
}
if (filters?.visibility) {
conditions.push('metadata_visibility = @visibility');
request.input('visibility', this.sql.VarChar(20), filters.visibility);
}
if (conditions.length > 0) {
sql += ' AND ' + conditions.join(' AND ');
}
sql += ' ORDER BY metadata_created DESC';
if (filters?.limit) {
if (filters?.offset) {
sql += ` OFFSET ROWS FETCH NEXT ROWS ONLY`;
request.input('offset', this.sql.Int, filters.offset);
request.input('limit', this.sql.Int, filters.limit);
} else {
sql = `SELECT TOP () * FROM (${sql}) AS ordered_results`;
request.input('limit', this.sql.Int, filters.limit);
}
}
const result = await request.query(sql);
return (result.recordset || []).map((row: any) => this.mapRowToAsset(row));
} catch (error) {
throw error;
}
}
async saveAssetsBatch(assets: Asset[]): Promise<string[]> {
this.assertConnected();
const transaction = new this.sql.Transaction(this.pool);
try {
await transaction.begin();
const ids: string[] = [];
for (const asset of assets) {
const id = await this.saveAssetInTransaction(transaction, asset);
ids.push(id);
}
await transaction.commit();
return ids;
} catch (error) {
await transaction.rollback();
throw error;
}
}
async beginTransaction(): Promise<Transaction> {
this.assertConnected();
const transaction = new this.sql.Transaction(this.pool);
await transaction.begin();
return {
async commit() {
await transaction.commit();
},
async rollback() {
await transaction.rollback();
}
};
}
private async ensureTablesExist(): Promise<void> {
const request = this.pool!.request();
try {
const checkTableSql = `
SELECT COUNT(*) as count
FROM INFORMATION_SCHEMA.TABLES
WHERE TABLE_NAME = 'defarm_assets'
`;
const result = await request.query(checkTableSql);
const tableExists = result.recordset[0].count > 0;
if (!tableExists) {
const createTableSql = `
CREATE TABLE defarm_assets (
id VARCHAR(255) PRIMARY KEY,
dfid VARCHAR(255) UNIQUE,
name NVARCHAR(500) NOT NULL,
category VARCHAR(50) NOT NULL,
subcategory VARCHAR(100) NOT NULL,
-- Ownership information
owner_id VARCHAR(255) NOT NULL,
owner_name NVARCHAR(500) NOT NULL,
location_country VARCHAR(100),
location_state VARCHAR(100),
location_municipality NVARCHAR(200),
location_coordinates NVARCHAR(MAX),
-- Asset-specific data (flexible JSON)
asset_data NVARCHAR(MAX) NOT NULL CHECK (ISJSON(asset_data) = 1),
-- Metadata
metadata_source VARCHAR(50) NOT NULL CHECK (metadata_source IN ('producer', 'authority', 'enterprise', 'association')),
metadata_from_producer BIT NOT NULL DEFAULT 0,
metadata_visibility VARCHAR(20) NOT NULL CHECK (metadata_visibility IN ('public', 'private', 'partners')),
metadata_created DATETIMEOFFSET NOT NULL DEFAULT GETUTCDATE(),
metadata_updated DATETIMEOFFSET NOT NULL DEFAULT GETUTCDATE(),
metadata_version INT NOT NULL DEFAULT 1,
CONSTRAINT chk_location_coordinates CHECK (
location_coordinates IS NULL OR ISJSON(location_coordinates) = 1
)
);
`;
await request.query(createTableSql);
const indexes = [
'CREATE INDEX IX_defarm_assets_category ON defarm_assets(category)',
'CREATE INDEX IX_defarm_assets_owner_id ON defarm_assets(owner_id)',
'CREATE INDEX IX_defarm_assets_country ON defarm_assets(location_country)',
'CREATE INDEX IX_defarm_assets_from_producer ON defarm_assets(metadata_from_producer)',
'CREATE INDEX IX_defarm_assets_visibility ON defarm_assets(metadata_visibility)',
'CREATE INDEX IX_defarm_assets_created ON defarm_assets(metadata_created)',
'CREATE INDEX IX_defarm_assets_dfid ON defarm_assets(dfid)'
];
for (const indexSql of indexes) {
try {
await request.query(indexSql);
} catch (error) {
console.warn(`Failed to create index: ${error}`);
}
}
const triggerSql = `
CREATE TRIGGER trg_defarm_assets_updated
ON defarm_assets
AFTER UPDATE
AS
BEGIN
SET NOCOUNT ON;
UPDATE defarm_assets
SET metadata_updated = GETUTCDATE()
FROM defarm_assets da
INNER JOIN inserted i ON da.id = i.id;
END;
`;
await request.query(triggerSql);
}
} catch (error) {
throw error;
}
}
private async saveAssetInTransaction(transaction: any, asset: Asset): Promise<string> {
const request = new this.sql.Request(transaction);
const assetId = asset.id || this.generateId();
const sql = `
MERGE defarm_assets AS target
USING (SELECT AS id) AS source
ON target.id = source.id
WHEN MATCHED THEN
UPDATE SET
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_updated = GETUTCDATE(),
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 (
, , , , ,
, , , ,
, ,
, , ,
, GETUTCDATE(), GETUTCDATE(),
);
`;
request.input('id', this.sql.VarChar(255), assetId);
request.input('dfid', this.sql.VarChar(255), asset.dfid);
request.input('name', this.sql.NVarChar(500), asset.name);
request.input('category', this.sql.VarChar(50), asset.category);
request.input('subcategory', this.sql.VarChar(100), asset.subcategory);
request.input('owner_id', this.sql.VarChar(255), asset.ownership.ownerId);
request.input('owner_name', this.sql.NVarChar(500), asset.ownership.ownerName);
request.input('location_country', this.sql.VarChar(100), asset.ownership.location?.country);
request.input('location_state', this.sql.VarChar(100), asset.ownership.location?.state);
request.input('location_municipality', this.sql.NVarChar(200), asset.ownership.location?.municipality);
request.input('location_coordinates', this.sql.NVarChar(this.sql.MAX),
asset.ownership.location?.coordinates ? JSON.stringify(asset.ownership.location.coordinates) : null);
request.input('asset_data', this.sql.NVarChar(this.sql.MAX), JSON.stringify(asset.data));
request.input('metadata_source', this.sql.VarChar(50), asset.metadata.source);
request.input('metadata_from_producer', this.sql.Bit, asset.metadata.fromProducer);
request.input('metadata_visibility', this.sql.VarChar(20), asset.metadata.visibility);
request.input('metadata_version', this.sql.Int, asset.metadata.version);
await request.query(sql);
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,
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('SQL Server adapter not connected. Call connect() first.');
}
}
private generateId(): string {
return `sql_${Date.now()}_${Math.random().toString(36).substring(7)}`;
}
}