UNPKG

defarm-sdk

Version:

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

421 lines (363 loc) 13.4 kB
import { Pool, PoolConfig, Client } from 'pg'; import type { StorageAdapter, Asset, Transaction } from '../types'; export interface PostgreSQLConfig extends PoolConfig { host: string; port: number; database: string; user: string; password: string; ssl?: boolean | object; max?: number; idleTimeoutMillis?: number; connectionTimeoutMillis?: number; } export class PostgreSQLAdapter implements StorageAdapter { private pool: Pool | null = null; private config: PostgreSQLConfig; constructor(config: PostgreSQLConfig) { this.config = { max: 20, idleTimeoutMillis: 30000, connectionTimeoutMillis: 2000, ...config }; } async connect(): Promise<void> { if (this.pool) { return; } this.pool = new Pool(this.config); this.pool.on('error', (err) => { console.error('PostgreSQL pool error:', err); }); try { const client = await this.pool.connect(); client.release(); await this.ensureTablesExist(); } catch (error) { throw new Error(`Failed to connect to PostgreSQL: ${error instanceof Error ? error.message : 'Unknown error'}`); } } async disconnect(): Promise<void> { if (this.pool) { await this.pool.end(); this.pool = null; } } async saveAsset(asset: Asset): Promise<string> { this.assertConnected(); const client = await this.pool!.connect(); try { const assetId = asset.id || this.generateId(); const query = ` INSERT INTO defarm_assets ( 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 ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18) ON CONFLICT (id) DO UPDATE SET dfid = EXCLUDED.dfid, name = EXCLUDED.name, category = EXCLUDED.category, subcategory = EXCLUDED.subcategory, owner_id = EXCLUDED.owner_id, owner_name = EXCLUDED.owner_name, location_country = EXCLUDED.location_country, location_state = EXCLUDED.location_state, location_municipality = EXCLUDED.location_municipality, location_coordinates = EXCLUDED.location_coordinates, asset_data = EXCLUDED.asset_data, metadata_source = EXCLUDED.metadata_source, metadata_from_producer = EXCLUDED.metadata_from_producer, metadata_visibility = EXCLUDED.metadata_visibility, metadata_updated = EXCLUDED.metadata_updated, metadata_version = EXCLUDED.metadata_version RETURNING id `; const values = [ assetId, asset.dfid, asset.name, asset.category, asset.subcategory, asset.ownership.ownerId, asset.ownership.ownerName, asset.ownership.location?.country, asset.ownership.location?.state, asset.ownership.location?.municipality, asset.ownership.location?.coordinates ? JSON.stringify(asset.ownership.location.coordinates) : null, JSON.stringify(asset.data), asset.metadata.source, asset.metadata.fromProducer, asset.metadata.visibility, asset.metadata.created, asset.metadata.updated, asset.metadata.version ]; const result = await client.query(query, values); return result.rows[0].id; } finally { client.release(); } } async getAsset(id: string): Promise<Asset | null> { this.assertConnected(); const client = await this.pool!.connect(); try { const query = ` SELECT * FROM defarm_assets WHERE id = $1 `; const result = await client.query(query, [id]); if (result.rows.length === 0) { return null; } return this.mapRowToAsset(result.rows[0]); } finally { client.release(); } } async queryAssets(filters?: { category?: string; ownerId?: string; country?: string; fromProducer?: boolean; visibility?: string; limit?: number; offset?: number; }): Promise<Asset[]> { this.assertConnected(); const client = await this.pool!.connect(); try { let query = 'SELECT * FROM defarm_assets WHERE 1=1'; const values: any[] = []; let paramCounter = 1; if (filters?.category) { query += ` AND category = $${paramCounter++}`; values.push(filters.category); } if (filters?.ownerId) { query += ` AND owner_id = $${paramCounter++}`; values.push(filters.ownerId); } if (filters?.country) { query += ` AND location_country = $${paramCounter++}`; values.push(filters.country); } if (filters?.fromProducer !== undefined) { query += ` AND metadata_from_producer = $${paramCounter++}`; values.push(filters.fromProducer); } if (filters?.visibility) { query += ` AND metadata_visibility = $${paramCounter++}`; values.push(filters.visibility); } query += ' ORDER BY metadata_created DESC'; if (filters?.limit) { query += ` LIMIT $${paramCounter++}`; values.push(filters.limit); } if (filters?.offset) { query += ` OFFSET $${paramCounter++}`; values.push(filters.offset); } const result = await client.query(query, values); return result.rows.map(row => this.mapRowToAsset(row)); } finally { client.release(); } } async saveAssetsBatch(assets: Asset[]): Promise<string[]> { this.assertConnected(); const client = await this.pool!.connect(); try { await client.query('BEGIN'); const ids: string[] = []; for (const asset of assets) { const id = await this.saveAssetInTransaction(client, asset); ids.push(id); } await client.query('COMMIT'); return ids; } catch (error) { await client.query('ROLLBACK'); throw error; } finally { client.release(); } } async beginTransaction(): Promise<Transaction> { this.assertConnected(); const client = await this.pool!.connect(); await client.query('BEGIN'); return { async commit() { try { await client.query('COMMIT'); } finally { client.release(); } }, async rollback() { try { await client.query('ROLLBACK'); } finally { client.release(); } } }; } private async ensureTablesExist(): Promise<void> { const client = await this.pool!.connect(); try { const createTableQuery = ` CREATE TABLE IF NOT EXISTS defarm_assets ( id VARCHAR(255) PRIMARY KEY, dfid VARCHAR(255) UNIQUE, name VARCHAR(500) NOT NULL, category VARCHAR(50) NOT NULL, subcategory VARCHAR(100) NOT NULL, -- Ownership information owner_id VARCHAR(255) NOT NULL, owner_name VARCHAR(500) NOT NULL, location_country VARCHAR(100), location_state VARCHAR(100), location_municipality VARCHAR(200), location_coordinates JSONB, -- Asset-specific data (flexible JSON) asset_data JSONB NOT NULL DEFAULT '{}', -- Metadata metadata_source VARCHAR(50) NOT NULL CHECK (metadata_source IN ('producer', 'authority', 'enterprise', 'association')), metadata_from_producer BOOLEAN NOT NULL DEFAULT false, metadata_visibility VARCHAR(20) NOT NULL CHECK (metadata_visibility IN ('public', 'private', 'partners')), metadata_created TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), metadata_updated TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), metadata_version INTEGER NOT NULL DEFAULT 1, -- Indexes for common queries CONSTRAINT valid_coordinates CHECK ( location_coordinates IS NULL OR (jsonb_array_length(location_coordinates) = 2 AND (location_coordinates->>0)::numeric BETWEEN -180 AND 180 AND (location_coordinates->>1)::numeric BETWEEN -90 AND 90) ) ); -- Create indexes for performance CREATE INDEX IF NOT EXISTS idx_defarm_assets_category ON defarm_assets(category); CREATE INDEX IF NOT EXISTS idx_defarm_assets_owner_id ON defarm_assets(owner_id); CREATE INDEX IF NOT EXISTS idx_defarm_assets_country ON defarm_assets(location_country); CREATE INDEX IF NOT EXISTS idx_defarm_assets_from_producer ON defarm_assets(metadata_from_producer); CREATE INDEX IF NOT EXISTS idx_defarm_assets_visibility ON defarm_assets(metadata_visibility); CREATE INDEX IF NOT EXISTS idx_defarm_assets_created ON defarm_assets(metadata_created); CREATE INDEX IF NOT EXISTS idx_defarm_assets_dfid ON defarm_assets(dfid); -- Create GIN index for asset_data JSON queries CREATE INDEX IF NOT EXISTS idx_defarm_assets_data_gin ON defarm_assets USING GIN (asset_data); -- Create GIN index for location coordinates CREATE INDEX IF NOT EXISTS idx_defarm_assets_coordinates_gin ON defarm_assets USING GIN (location_coordinates); -- Update trigger for metadata_updated CREATE OR REPLACE FUNCTION update_modified_column() RETURNS TRIGGER AS $$ BEGIN NEW.metadata_updated = NOW(); RETURN NEW; END; $$ language 'plpgsql'; DROP TRIGGER IF EXISTS update_defarm_assets_modtime ON defarm_assets; CREATE TRIGGER update_defarm_assets_modtime BEFORE UPDATE ON defarm_assets FOR EACH ROW EXECUTE FUNCTION update_modified_column(); `; await client.query(createTableQuery); } finally { client.release(); } } private async saveAssetInTransaction(client: Client, asset: Asset): Promise<string> { const assetId = asset.id || this.generateId(); const query = ` INSERT INTO defarm_assets ( 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 ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13, $14, $15, $16, $17, $18) ON CONFLICT (id) DO UPDATE SET dfid = EXCLUDED.dfid, name = EXCLUDED.name, category = EXCLUDED.category, subcategory = EXCLUDED.subcategory, owner_id = EXCLUDED.owner_id, owner_name = EXCLUDED.owner_name, location_country = EXCLUDED.location_country, location_state = EXCLUDED.location_state, location_municipality = EXCLUDED.location_municipality, location_coordinates = EXCLUDED.location_coordinates, asset_data = EXCLUDED.asset_data, metadata_source = EXCLUDED.metadata_source, metadata_from_producer = EXCLUDED.metadata_from_producer, metadata_visibility = EXCLUDED.metadata_visibility, metadata_updated = EXCLUDED.metadata_updated, metadata_version = EXCLUDED.metadata_version RETURNING id `; const values = [ assetId, asset.dfid, asset.name, asset.category, asset.subcategory, asset.ownership.ownerId, asset.ownership.ownerName, asset.ownership.location?.country, asset.ownership.location?.state, asset.ownership.location?.municipality, asset.ownership.location?.coordinates ? JSON.stringify(asset.ownership.location.coordinates) : null, JSON.stringify(asset.data), asset.metadata.source, asset.metadata.fromProducer, asset.metadata.visibility, asset.metadata.created, asset.metadata.updated, asset.metadata.version ]; const result = await client.query(query, values); return result.rows[0].id; } 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: 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('PostgreSQL adapter not connected. Call connect() first.'); } } private generateId(): string { return `pg_${Date.now()}_${Math.random().toString(36).substring(7)}`; } }