From 34ab6496b83c8d04770d42ff581dc444c1f79452 Mon Sep 17 00:00:00 2001 From: sigmatics Date: Tue, 6 Oct 2020 09:14:21 +0200 Subject: [PATCH] Transform SQL queries to parameterized queries (prepared statements) [BE-833] (#192) Signed-off-by: sigma67 --- app/persistence/fabric/CRUDService.ts | 137 ++++++++++++------------ app/persistence/fabric/MetricService.ts | 100 +++++++++-------- app/persistence/postgreSQL/PgService.ts | 37 +++---- app/rest/dbroutes.ts | 4 +- app/rest/requestutils.ts | 24 ++--- 5 files changed, 151 insertions(+), 151 deletions(-) diff --git a/app/persistence/fabric/CRUDService.ts b/app/persistence/fabric/CRUDService.ts index f943efb32..3c4abd018 100644 --- a/app/persistence/fabric/CRUDService.ts +++ b/app/persistence/fabric/CRUDService.ts @@ -29,7 +29,8 @@ export class CRUDService { getTxCountByBlockNum(network_name: any, channel_genesis_hash: any, blockNum: any) { return this.sql.getRowByPkOne( - `select blocknum ,txcount from blocks where channel_genesis_hash='${channel_genesis_hash}' and blocknum=${blockNum} and network_name = '${network_name}' ` + `select blocknum ,txcount from blocks where channel_genesis_hash=$1 and blocknum=$2 and network_name = $3`, + [channel_genesis_hash, blockNum, network_name] ); } @@ -44,8 +45,8 @@ export class CRUDService { getTransactionByID(network_name: any, channel_genesis_hash: any, txhash: any) { const sqlTxById = ` select t.txhash,t.validation_code,t.payload_proposal_hash,t.creator_msp_id,t.endorser_msp_id,t.chaincodename,t.type,t.createdt,t.read_set, t.write_set,channel.name as channelName from TRANSACTIONS as t inner join channel on t.channel_genesis_hash=channel.channel_genesis_hash and t.network_name=channel.network_name - where t.txhash = '${txhash}' and t.network_name = '${network_name}' `; - return this.sql.getRowByPkOne(sqlTxById); + where t.txhash = $1 and t.network_name = $2 `; + return this.sql.getRowByPkOne(sqlTxById, [txhash, network_name]); } /** @@ -59,11 +60,11 @@ export class CRUDService { getBlockActivityList(network_name: any, channel_genesis_hash: any) { const sqlBlockActivityList = `select blocks.blocknum,blocks.txcount ,blocks.datahash ,blocks.blockhash ,blocks.prehash,blocks.createdt, ( SELECT array_agg(txhash) as txhash FROM transactions where blockid = blocks.blocknum and - channel_genesis_hash = '${channel_genesis_hash}' and network_name = '${network_name}' group by transactions.blockid ), + channel_genesis_hash = $1 and network_name = $2 group by transactions.blockid ), channel.name as channelname from blocks inner join channel on blocks.channel_genesis_hash = channel.channel_genesis_hash where - blocks.channel_genesis_hash ='${channel_genesis_hash}' and blocknum >= 0 and blocks.network_name = '${network_name}' + blocks.channel_genesis_hash = $1 and blocknum >= 0 and blocks.network_name = $2 order by blocks.blocknum desc limit 3`; - return this.sql.getRowsBySQlQuery(sqlBlockActivityList); + return this.sql.getRowsBySQlQuery(sqlBlockActivityList, [channel_genesis_hash, network_name]); } /** @@ -79,25 +80,19 @@ export class CRUDService { * @memberof CRUDService */ getTxList(network_name: any, channel_genesis_hash: any, blockNum: any, txid: any, from: any, to: any, orgs: string) { - let byOrgs = false; - if (orgs && orgs !== '') { - byOrgs = true; - } - - logger.debug('getTxList.byOrgs ', byOrgs); - const sqlTxListByOrgs = ` select t.creator_msp_id,t.txhash,t.type,t.chaincodename,t.createdt,channel.name as channelName from transactions as t - inner join channel on t.channel_genesis_hash=channel.channel_genesis_hash and t.network_name = channel.network_name where t.blockid >= ${blockNum} and t.id >= ${txid} and t.creator_msp_id in (${orgs}) and - t.channel_genesis_hash = '${channel_genesis_hash}' and t.network_name = '${network_name}' and t.createdt between '${from}' and '${to}' order by t.id desc`; + let sqlTxList = ` select t.creator_msp_id,t.txhash,t.type,t.chaincodename,t.createdt,channel.name as channelName from transactions as t + inner join channel on t.channel_genesis_hash=channel.channel_genesis_hash and t.network_name = channel.network_name where t.blockid >= $1 and t.id >= $2 and + t.channel_genesis_hash = $3 and t.network_name = $4 and t.createdt between $5 and $6 `; + let values = [blockNum, txid, channel_genesis_hash, network_name, from, to] - const sqlTxList = ` select t.creator_msp_id,t.txhash,t.type,t.chaincodename,t.createdt,channel.name as channelName from transactions as t - inner join channel on t.channel_genesis_hash=channel.channel_genesis_hash and t.network_name = channel.network_name where t.blockid >= ${blockNum} and t.id >= ${txid} and - t.channel_genesis_hash = '${channel_genesis_hash}' and t.network_name = '${network_name}' and t.createdt between '${from}' and '${to}' order by t.id desc`; - - if (byOrgs) { - return this.sql.getRowsBySQlQuery(sqlTxListByOrgs); + if (orgs && orgs.length > 0) { + sqlTxList += ` and t.creator_msp_id = ANY($7)`; + values.push(orgs) } - return this.sql.getRowsBySQlQuery(sqlTxList); + sqlTxList += ' order by t.createdt desc'; + + return this.sql.getRowsBySQlQuery(sqlTxList, values); } /** @@ -118,40 +113,28 @@ export class CRUDService { blockNum: any, from: any, to: any, - orgs: string + orgs: string[] ) { - let byOrgs = false; - // workaround for SQL injection - if (orgs && orgs !== '') { - byOrgs = true; + let values = [channel_genesis_hash, network_name, from, to]; + let byOrgs = ''; + if (orgs && orgs.length > 0) { + values.push(orgs); + byOrgs = ` and creator_msp_id = ANY($5)`; } logger.debug('getBlockAndTxList.byOrgs ', byOrgs); - + const sqlBlockTxList = `select a.* from ( - select (select c.name from channel c where c.channel_genesis_hash = - '${channel_genesis_hash}' and c.network_name = '${network_name}') as channelname, blocks.blocknum,blocks.txcount ,blocks.datahash ,blocks.blockhash ,blocks.prehash,blocks.createdt, blocks.blksize, ( - SELECT array_agg(txhash) as txhash FROM transactions where blockid = blocks.blocknum and - channel_genesis_hash = '${channel_genesis_hash}' and network_name = '${network_name}' and createdt between '${from}' and '${to}') from blocks where - blocks.channel_genesis_hash ='${channel_genesis_hash}' and blocks.network_name = '${network_name}' and blocknum >= 0 and blocks.createdt between '${from}' and '${to}' + select (select c.name from channel c where c.channel_genesis_hash =$1 and c.network_name = $2) + as channelname, blocks.blocknum,blocks.txcount ,blocks.datahash ,blocks.blockhash ,blocks.prehash,blocks.createdt, blocks.blksize, ( + SELECT array_agg(txhash) as txhash FROM transactions where blockid = blocks.blocknum ${byOrgs} and + channel_genesis_hash = $1 and network_name = $2 and createdt between $3 and $4) from blocks where + blocks.channel_genesis_hash =$1 and blocks.network_name = $2 and blocknum >= 0 and blocks.createdt between $3 and $4 order by blocks.blocknum desc) a where a.txhash IS NOT NULL`; - + logger.debug('sqlBlockTxList ', sqlBlockTxList); - const sqlBlockTxListByOrgs = `select a.* from ( - select (select c.name from channel c where c.channel_genesis_hash = - '${channel_genesis_hash}' and c.network_name = '${network_name}' ) as channelname, blocks.blocknum,blocks.txcount ,blocks.datahash ,blocks.blockhash ,blocks.prehash,blocks.createdt, blocks.blksize, ( - SELECT array_agg(txhash) as txhash FROM transactions where blockid = blocks.blocknum and creator_msp_id in (${orgs}) and - channel_genesis_hash = '${channel_genesis_hash}' and network_name = '${network_name}' and createdt between '${from}' and '${to}') from blocks where - blocks.channel_genesis_hash ='${channel_genesis_hash}' and blocks.network_name = '${network_name}' and blocknum >= 0 and blocks.createdt between '${from}' and '${to}' - order by blocks.blocknum desc) a where a.txhash IS NOT NULL`; - if (byOrgs) { - return this.sql.getRowsBySQlQuery(sqlBlockTxListByOrgs); - } - const ret = this.sql.getRowsBySQlQuery(sqlBlockTxList); - logger.debug('Finished sqlBlockTxList ', ret); - - return ret; + return this.sql.getRowsBySQlQuery(sqlBlockTxList, values); } /** @@ -164,7 +147,8 @@ export class CRUDService { async getChannelConfig(network_name: any, channel_genesis_hash: any) { const channelConfig = await this.sql.getRowsBySQlCase( - ` select * from channel where channel_genesis_hash ='${channel_genesis_hash}' and network_name = '${network_name}' ` + ` select * from channel where channel_genesis_hash =$1 and network_name = $2 `, + [channel_genesis_hash, network_name] ); return channelConfig; } @@ -179,7 +163,8 @@ export class CRUDService { */ async getChannel(network_name: any, channelname: any, channel_genesis_hash: any) { const channel = await this.sql.getRowsBySQlCase( - ` select * from channel where name='${channelname}' and channel_genesis_hash='${channel_genesis_hash}' and network_name = '${network_name}' ` + ` select * from channel where name=$1 and channel_genesis_hash=$2 and network_name = $3 `, + [channelname, channel_genesis_hash, network_name] ); return channel; } @@ -192,7 +177,8 @@ export class CRUDService { */ async existChannel(network_name: any, channelname: any) { const channel = await this.sql.getRowsBySQlCase( - ` select count(1) from channel where name='${channelname}' and network_name = '${network_name}' ` + ` select count(1) from channel where name=$1 and network_name = $2 `, + [channelname, network_name] ); return channel; } @@ -208,14 +194,16 @@ export class CRUDService { async saveBlock(network_name, block) { const c = await this.sql - .getRowByPkOne(`select count(1) as c from blocks where blocknum='${block.blocknum}' and txcount='${block.txcount}' - and channel_genesis_hash='${block.channel_genesis_hash}' and network_name = '${network_name}' and prehash='${block.prehash}' and datahash='${block.datahash}' `); + .getRowByPkOne(`select count(1) as c from blocks where blocknum=$1 and txcount=$2 + and channel_genesis_hash=$3 and network_name =$4 and prehash=$5 and datahash=$6 `, + [block.blocknum, block.txcount, block.channel_genesis_hash, network_name, block.prehash, block.datahash]); if (isValidRow(c)) { block.network_name = network_name; await this.sql.saveRow('blocks', block); await this.sql.updateBySql( - `update channel set blocks =blocks+1 where channel_genesis_hash='${block.channel_genesis_hash}' and network_name = '${network_name}' ` + `update channel set blocks =blocks+1 where channel_genesis_hash=$1 and network_name = $2 `, + [block.channel_genesis_hash, network_name] ); return true; } @@ -234,17 +222,20 @@ export class CRUDService { */ async saveTransaction(network_name, transaction) { const c = await this.sql.getRowByPkOne( - `select count(1) as c from transactions where blockid='${transaction.blockid}' and txhash='${transaction.txhash}' and channel_genesis_hash='${transaction.channel_genesis_hash}' and network_name = '${network_name}' ` + `select count(1) as c from transactions where blockid=$1 and txhash=$2 and channel_genesis_hash=$3 and network_name = $4 `, + [transaction.blockid, transaction.txhash, transaction.channel_genesis_hash, network_name] ); if (isValidRow(c)) { transaction.network_name = network_name; await this.sql.saveRow('transactions', transaction); await this.sql.updateBySql( - `update chaincodes set txcount =txcount+1 where channel_genesis_hash='${transaction.channel_genesis_hash}' and network_name = '${network_name}' and name='${transaction.chaincodename}'` + `update chaincodes set txcount =txcount+1 where channel_genesis_hash=$1 and network_name = $2 and name=$3`, + [transaction.channel_genesis_hash, network_name, transaction.chaincodename] ); await this.sql.updateBySql( - `update channel set trans =trans+1 where channel_genesis_hash='${transaction.channel_genesis_hash}' and network_name = '${network_name}' ` + `update channel set trans =trans+1 where channel_genesis_hash=$1 and network_name = $2 `, + [transaction.channel_genesis_hash, network_name] ); return true; } @@ -263,7 +254,8 @@ export class CRUDService { let curBlockNum; try { const row : any = await this.sql.getRowsBySQlCase( - `select max(blocknum) as blocknum from blocks where channel_genesis_hash='${channel_genesis_hash}' and network_name = '${network_name}' ` + `select max(blocknum) as blocknum from blocks where channel_genesis_hash=$1 and network_name = $2 `, + [channel_genesis_hash, network_name] ); if (row && row.blocknum) { @@ -288,8 +280,9 @@ export class CRUDService { */ async saveChaincode(network_name, chaincode) { const c = await this.sql - .getRowByPkOne(`select count(1) as c from chaincodes where name='${chaincode.name}' and - channel_genesis_hash='${chaincode.channel_genesis_hash}' and network_name = '${network_name}' and version='${chaincode.version}' and path='${chaincode.path}'`); + .getRowByPkOne(`select count(1) as c from chaincodes where name=$1 and + channel_genesis_hash=$2 and network_name = $3 and version=$4 and path=$5`, + [chaincode.name, chaincode.channel_genesis_hash, network_name, chaincode.version, chaincode.path]); if (isValidRow(c)) { chaincode.network_name = network_name; @@ -307,7 +300,8 @@ export class CRUDService { */ getChannelByGenesisBlockHash(network_name, channel_genesis_hash) { return this.sql.getRowByPkOne( - `select name from channel where channel_genesis_hash='${channel_genesis_hash}' and network_name = '${network_name}' ` + `select name from channel where channel_genesis_hash=$1 and network_name = $2 `, + [channel_genesis_hash, network_name] ); } @@ -319,7 +313,8 @@ export class CRUDService { */ async saveChaincodPeerRef(network_name, peers_ref_chaincode) { const c = await this.sql.getRowByPkOne( - `select count(1) as c from peer_ref_chaincode prc where prc.peerid= '${peers_ref_chaincode.peerid}' and prc.chaincodeid='${peers_ref_chaincode.chaincodeid}' and cc_version='${peers_ref_chaincode.cc_version}' and channelid='${peers_ref_chaincode.channelid}' and network_name = '${network_name}' ` + `select count(1) as c from peer_ref_chaincode prc where prc.peerid=$1 and prc.chaincodeid=$2 and cc_version=$3 and channelid=$4 and network_name = $5 `, + [peers_ref_chaincode.peerid, peers_ref_chaincode.chaincodeid, peers_ref_chaincode.cc_version, peers_ref_chaincode.channelid, network_name] ); if (isValidRow(c)) { @@ -336,7 +331,8 @@ export class CRUDService { */ async saveChannel(network_name, channel) { const c = await this.sql.getRowByPkOne( - `select count(1) as c from channel where name='${channel.name}' and channel_genesis_hash='${channel.channel_genesis_hash}' and network_name = '${network_name}' ` + `select count(1) as c from channel where name=$1 and channel_genesis_hash=$2 and network_name = $3 `, + [channel.name, channel.channel_genesis_hash, network_name] ); if (isValidRow(c)) { @@ -351,7 +347,8 @@ export class CRUDService { }); } else { await this.sql.updateBySql( - `update channel set blocks='${channel.blocks}',trans='${channel.trans}',channel_hash='${channel.channel_hash}' where name='${channel.name}'and channel_genesis_hash='${channel.channel_genesis_hash}' and network_name = '${network_name}' ` + `update channel set blocks=$1,trans=$2,channel_hash=$3 where name=$4 and channel_genesis_hash=$5 and network_name = $6 `, + [channel.blocks, channel.trans, channel.channel_hash, channel.name, channel.channel_genesis_hash, network_name] ); } } @@ -364,7 +361,8 @@ export class CRUDService { */ async savePeer(network_name, peer) { const c = await this.sql.getRowByPkOne( - `select count(1) as c from peer where channel_genesis_hash='${peer.channel_genesis_hash}' and network_name = '${network_name}' and server_hostname='${peer.server_hostname}' ` + `select count(1) as c from peer where channel_genesis_hash=$1 and network_name = $2 and server_hostname=$3 `, + [peer.channel_genesis_hash, network_name, peer.server_hostname] ); if (isValidRow(c)) { @@ -381,7 +379,8 @@ export class CRUDService { */ async savePeerChannelRef(network_name, peers_ref_Channel) { const c = await this.sql.getRowByPkOne( - `select count(1) as c from peer_ref_channel prc where prc.peerid = '${peers_ref_Channel.peerid}' and network_name = '${network_name}' and prc.channelid='${peers_ref_Channel.channelid}' ` + `select count(1) as c from peer_ref_channel prc where prc.peerid = $1 and network_name = $2 and prc.channelid=$3 `, + [peers_ref_Channel.peerid, network_name, peers_ref_Channel.channelid] ); if (isValidRow(c)) { @@ -400,7 +399,8 @@ export class CRUDService { async getChannelsInfo(network_name) { const channels = await this.sql .getRowsBySQlNoCondition(` select c.id as id,c.name as channelName,c.blocks as blocks ,c.channel_genesis_hash as channel_genesis_hash,c.trans as transactions,c.createdt as createdat,c.channel_hash as channel_hash from channel c, - peer_ref_channel pc where c.channel_genesis_hash = pc.channelid and c.network_name = '${network_name}' group by c.id ,c.name ,c.blocks ,c.trans ,c.createdt ,c.channel_hash,c.channel_genesis_hash order by c.name `); + peer_ref_channel pc where c.channel_genesis_hash = pc.channelid and c.network_name = $1 group by c.id ,c.name ,c.blocks ,c.trans ,c.createdt ,c.channel_hash,c.channel_genesis_hash order by c.name `, + [network_name]); return channels; } @@ -414,7 +414,8 @@ export class CRUDService { */ async saveOrderer(network_name, orderer) { const c = await this.sql.getRowByPkOne( - `select count(1) as c from orderer where requests='${orderer.requests}' and network_name = '${network_name}' ` + `select count(1) as c from orderer where requests=$1 and network_name = $2 `, + [orderer.requests, network_name] ); if (isValidRow(c)) { orderer.network_name = network_name; diff --git a/app/persistence/fabric/MetricService.ts b/app/persistence/fabric/MetricService.ts index ff2ece9c3..76b911e10 100644 --- a/app/persistence/fabric/MetricService.ts +++ b/app/persistence/fabric/MetricService.ts @@ -27,7 +27,8 @@ export class MetricService { */ getChaincodeCount(network_name: any, channel_genesis_hash: any) { return this.sql.getRowsBySQlCase( - `select count(1) c from chaincodes where channel_genesis_hash='${channel_genesis_hash}' and network_name='${network_name}' ` + `select count(1) c from chaincodes where channel_genesis_hash=$1 and network_name=$2 `, + [channel_genesis_hash, network_name] ); } @@ -40,7 +41,8 @@ export class MetricService { */ getPeerlistCount(network_name: any, channel_genesis_hash: any) { return this.sql.getRowsBySQlCase( - `select count(1) c from peer where channel_genesis_hash='${channel_genesis_hash}' and peer_type='PEER' and network_name='${network_name}' ` + `select count(1) c from peer where channel_genesis_hash=$1 and peer_type='PEER' and network_name=$2 `, + [channel_genesis_hash, network_name] ); } @@ -53,7 +55,8 @@ export class MetricService { */ getTxCount(network_name: any, channel_genesis_hash: any) { return this.sql.getRowsBySQlCase( - `select count(1) c from transactions where channel_genesis_hash='${channel_genesis_hash}' and network_name='${network_name}' ` + `select count(1) c from transactions where channel_genesis_hash=$1 and network_name=$2 `, + [channel_genesis_hash, network_name] ); } @@ -66,7 +69,8 @@ export class MetricService { */ getBlockCount(network_name: any, channel_genesis_hash: any) { return this.sql.getRowsBySQlCase( - `select count(1) c from blocks where channel_genesis_hash='${channel_genesis_hash}' and network_name='${network_name}' ` + `select count(1) c from blocks where channel_genesis_hash=$1 and network_name=$2 `, + [channel_genesis_hash, network_name] ); } @@ -82,7 +86,8 @@ export class MetricService { const c1 = await this.sql .getRowsBySQlNoCondition(`select channel.name as channelName,c.requests as requests,c.channel_genesis_hash as channel_genesis_hash , c.server_hostname as server_hostname, c.mspid as mspid, c.peer_type as peer_type from peer as c inner join channel on - c.channel_genesis_hash=channel.channel_genesis_hash and c.network_name=channel.network_name where c.channel_genesis_hash='${channel_genesis_hash}' and c.network_name='${network_name}' `); + c.channel_genesis_hash=channel.channel_genesis_hash and c.network_name=channel.network_name where c.channel_genesis_hash=$1 and c.network_name=$2 `, + [channel_genesis_hash, network_name]); for (let i = 0, len = c1.length; i < len; i++) { const item = c1[i]; peerArray.push({ @@ -106,7 +111,8 @@ export class MetricService { async getOrdererData(network_name: any) { const ordererArray = []; const c1 = await this.sql.getRowsBySQlNoCondition( - `select c.requests as requests,c.server_hostname as server_hostname,c.channel_genesis_hash as channel_genesis_hash from orderer c where network_name='${network_name}' ` + `select c.requests as requests,c.server_hostname as server_hostname,c.channel_genesis_hash as channel_genesis_hash from orderer c where network_name=$1 `, + [network_name] ); for (let i = 0, len = c1.length; i < len; i++) { const item = c1[i]; @@ -130,7 +136,8 @@ export class MetricService { const txArray = []; const c = await this.sql .getRowsBySQlNoCondition(`select c.name as chaincodename,channel.name as channelname ,c.version as version,c.channel_genesis_hash - as channel_genesis_hash,c.path as path ,txcount as c from chaincodes as c inner join channel on c.channel_genesis_hash=channel.channel_genesis_hash and c.network_name=channel.network_name where c.channel_genesis_hash='${channel_genesis_hash}' and c.network_name='${network_name}' `); + as channel_genesis_hash,c.path as path ,txcount as c from chaincodes as c inner join channel on c.channel_genesis_hash=channel.channel_genesis_hash and c.network_name=channel.network_name where c.channel_genesis_hash=$1 and c.network_name=$2 `, + [channel_genesis_hash, network_name]); if (c) { c.forEach((item: { chaincodename: any; channelname: any; path: any; version: any; c: any; channel_genesis_hash: any; }, index: any) => { logger.debug(' item ------------> ', item); @@ -157,7 +164,8 @@ export class MetricService { async getOrgsData(network_name: any, channel_genesis_hash: any) { const orgs = []; const rows : any = await this.sql.getRowsBySQlNoCondition( - `select distinct on (mspid) mspid from peer where channel_genesis_hash='${channel_genesis_hash}' and network_name='${network_name}'` + `select distinct on (mspid) mspid from peer where channel_genesis_hash=$1 and network_name=$2`, + [channel_genesis_hash, network_name] ); for (let i = 0, len = rows.length; i < len; i++) { orgs.push(rows[i].mspid); @@ -297,7 +305,7 @@ export class MetricService { getTxByMinute(network_name: any, channel_genesis_hash: any, hours: any) { const sqlPerMinute = ` with minutes as ( select generate_series( - date_trunc('min', now()) - '${hours}hour'::interval, + date_trunc('min', now()) - '${hours} hour'::interval, date_trunc('min', now()), '1 min'::interval ) as datetime @@ -306,11 +314,11 @@ export class MetricService { minutes.datetime, count(createdt) from minutes - left join TRANSACTIONS on date_trunc('min', TRANSACTIONS.createdt) = minutes.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join TRANSACTIONS on date_trunc('min', TRANSACTIONS.createdt) = minutes.datetime and channel_genesis_hash =$1 and network_name=$2 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerMinute); + return this.sql.getRowsBySQlQuery(sqlPerMinute, [channel_genesis_hash, network_name]); } /** @@ -324,7 +332,7 @@ export class MetricService { getTxByHour(network_name: any, channel_genesis_hash: any, day: any) { const sqlPerHour = ` with hours as ( select generate_series( - date_trunc('hour', now()) - '${day}day'::interval, + date_trunc('hour', now()) - interval '1 day' * $1, date_trunc('hour', now()), '1 hour'::interval ) as datetime @@ -333,11 +341,11 @@ export class MetricService { hours.datetime, count(createdt) from hours - left join TRANSACTIONS on date_trunc('hour', TRANSACTIONS.createdt) = hours.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join TRANSACTIONS on date_trunc('hour', TRANSACTIONS.createdt) = hours.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerHour); + return this.sql.getRowsBySQlQuery(sqlPerHour, [day, channel_genesis_hash, network_name]); } /** @@ -351,7 +359,7 @@ export class MetricService { getTxByDay(network_name: any, channel_genesis_hash: any, days: any) { const sqlPerDay = ` with days as ( select generate_series( - date_trunc('day', now()) - '${days}day'::interval, + date_trunc('day', now()) - interval '1 day' * $1, date_trunc('day', now()), '1 day'::interval ) as datetime @@ -360,11 +368,11 @@ export class MetricService { days.datetime, count(createdt) from days - left join TRANSACTIONS on date_trunc('day', TRANSACTIONS.createdt) =days.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join TRANSACTIONS on date_trunc('day', TRANSACTIONS.createdt) =days.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerDay); + return this.sql.getRowsBySQlQuery(sqlPerDay, [days, channel_genesis_hash, network_name]); } /** @@ -378,7 +386,7 @@ export class MetricService { getTxByWeek(network_name: any, channel_genesis_hash: any, weeks: any) { const sqlPerWeek = ` with weeks as ( select generate_series( - date_trunc('week', now()) - '${weeks}week'::interval, + date_trunc('week', now()) - '$1 week'::interval, date_trunc('week', now()), '1 week'::interval ) as datetime @@ -387,11 +395,11 @@ export class MetricService { weeks.datetime, count(createdt) from weeks - left join TRANSACTIONS on date_trunc('week', TRANSACTIONS.createdt) =weeks.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join TRANSACTIONS on date_trunc('week', TRANSACTIONS.createdt) =weeks.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerWeek); + return this.sql.getRowsBySQlQuery(sqlPerWeek, [weeks, channel_genesis_hash, network_name]); } /** @@ -405,7 +413,7 @@ export class MetricService { getTxByMonth(network_name: any, channel_genesis_hash: any, months: any) { const sqlPerMonth = ` with months as ( select generate_series( - date_trunc('month', now()) - '${months}month'::interval, + date_trunc('month', now()) - '$1 month'::interval, date_trunc('month', now()), '1 month'::interval ) as datetime @@ -415,11 +423,11 @@ export class MetricService { months.datetime, count(createdt) from months - left join TRANSACTIONS on date_trunc('month', TRANSACTIONS.createdt) =months.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join TRANSACTIONS on date_trunc('month', TRANSACTIONS.createdt) =months.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerMonth); + return this.sql.getRowsBySQlQuery(sqlPerMonth, [months, channel_genesis_hash, network_name]); } /** @@ -433,7 +441,7 @@ export class MetricService { getTxByYear(network_name: any, channel_genesis_hash: any, years: any) { const sqlPerYear = ` with years as ( select generate_series( - date_trunc('year', now()) - '${years}year'::interval, + date_trunc('year', now()) - '$1 year'::interval, date_trunc('year', now()), '1 year'::interval ) as year @@ -442,11 +450,11 @@ export class MetricService { years.year, count(createdt) from years - left join TRANSACTIONS on date_trunc('year', TRANSACTIONS.createdt) =years.year and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join TRANSACTIONS on date_trunc('year', TRANSACTIONS.createdt) =years.year and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerYear); + return this.sql.getRowsBySQlQuery(sqlPerYear, [years, channel_genesis_hash, network_name]); } // Block metrics API @@ -461,7 +469,7 @@ export class MetricService { getBlocksByMinute(network_name: any, channel_genesis_hash: any, hours: any) { const sqlPerMinute = ` with minutes as ( select generate_series( - date_trunc('min', now()) - '${hours} hour'::interval, + date_trunc('min', now()) - interval '1 hour' * $1, date_trunc('min', now()), '1 min'::interval ) as datetime @@ -470,11 +478,11 @@ export class MetricService { minutes.datetime, count(createdt) from minutes - left join BLOCKS on date_trunc('min', BLOCKS.createdt) = minutes.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join BLOCKS on date_trunc('min', BLOCKS.createdt) = minutes.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerMinute); + return this.sql.getRowsBySQlQuery(sqlPerMinute, [hours, channel_genesis_hash, network_name]); } /** @@ -488,7 +496,7 @@ export class MetricService { getBlocksByHour(network_name: any, channel_genesis_hash: any, days: any) { const sqlPerHour = ` with hours as ( select generate_series( - date_trunc('hour', now()) - '${days}day'::interval, + date_trunc('hour', now()) - interval '1 day' * $1, date_trunc('hour', now()), '1 hour'::interval ) as datetime @@ -497,11 +505,11 @@ export class MetricService { hours.datetime, count(createdt) from hours - left join BLOCKS on date_trunc('hour', BLOCKS.createdt) = hours.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join BLOCKS on date_trunc('hour', BLOCKS.createdt) = hours.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerHour); + return this.sql.getRowsBySQlQuery(sqlPerHour, [days, channel_genesis_hash, network_name]); } /** @@ -524,11 +532,11 @@ export class MetricService { days.datetime, count(createdt) from days - left join BLOCKS on date_trunc('day', BLOCKS.createdt) =days.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join BLOCKS on date_trunc('day', BLOCKS.createdt) =days.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerDay); + return this.sql.getRowsBySQlQuery(sqlPerDay, [days, channel_genesis_hash, network_name]); } /** @@ -542,7 +550,7 @@ export class MetricService { getBlocksByWeek(network_name: any, channel_genesis_hash: any, weeks: any) { const sqlPerWeek = ` with weeks as ( select generate_series( - date_trunc('week', now()) - '${weeks}week'::interval, + date_trunc('week', now()) - '$1 week'::interval, date_trunc('week', now()), '1 week'::interval ) as datetime @@ -551,11 +559,11 @@ export class MetricService { weeks.datetime, count(createdt) from weeks - left join BLOCKS on date_trunc('week', BLOCKS.createdt) =weeks.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join BLOCKS on date_trunc('week', BLOCKS.createdt) =weeks.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerWeek); + return this.sql.getRowsBySQlQuery(sqlPerWeek, [weeks, channel_genesis_hash, network_name]); } /** @@ -569,7 +577,7 @@ export class MetricService { getBlocksByMonth(network_name: any, channel_genesis_hash: any, months: any) { const sqlPerMonth = ` with months as ( select generate_series( - date_trunc('month', now()) - '${months}month'::interval, + date_trunc('month', now()) - '$1 month'::interval, date_trunc('month', now()), '1 month'::interval ) as datetime @@ -578,11 +586,11 @@ export class MetricService { months.datetime, count(createdt) from months - left join BLOCKS on date_trunc('month', BLOCKS.createdt) =months.datetime and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join BLOCKS on date_trunc('month', BLOCKS.createdt) =months.datetime and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerMonth); + return this.sql.getRowsBySQlQuery(sqlPerMonth, [months, channel_genesis_hash, network_name]); } /** @@ -605,11 +613,11 @@ export class MetricService { years.year, count(createdt) from years - left join BLOCKS on date_trunc('year', BLOCKS.createdt) =years.year and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + left join BLOCKS on date_trunc('year', BLOCKS.createdt) =years.year and channel_genesis_hash=$2 and network_name=$3 group by 1 order by 1 `; - return this.sql.getRowsBySQlQuery(sqlPerYear); + return this.sql.getRowsBySQlQuery(sqlPerYear, [years, channel_genesis_hash, network_name]); } /** @@ -622,10 +630,10 @@ export class MetricService { getTxByOrgs(network_name: any, channel_genesis_hash: any) { const sqlPerOrg = ` select count(creator_msp_id), creator_msp_id from transactions - where channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' + where channel_genesis_hash =$1 and network_name=$2 group by creator_msp_id`; - return this.sql.getRowsBySQlQuery(sqlPerOrg); + return this.sql.getRowsBySQlQuery(sqlPerOrg, [channel_genesis_hash, network_name]); } /** @@ -638,8 +646,8 @@ export class MetricService { */ async findMissingBlockNumber(network_name: any, channel_genesis_hash: any, maxHeight: any) { const sqlQuery = `SELECT s.id AS missing_id - FROM generate_series(0, ${maxHeight}) s(id) WHERE NOT EXISTS (SELECT 1 FROM blocks WHERE blocknum = s.id and channel_genesis_hash ='${channel_genesis_hash}' and network_name='${network_name}' )`; + FROM generate_series(0, $1) s(id) WHERE NOT EXISTS (SELECT 1 FROM blocks WHERE blocknum = s.id and channel_genesis_hash=$2 and network_name=$3 )`; - return this.sql.getRowsBySQlQuery(sqlQuery); + return this.sql.getRowsBySQlQuery(sqlQuery, [maxHeight, channel_genesis_hash, network_name]); } } diff --git a/app/persistence/postgreSQL/PgService.ts b/app/persistence/postgreSQL/PgService.ts index f93429451..6a4784e35 100644 --- a/app/persistence/postgreSQL/PgService.ts +++ b/app/persistence/postgreSQL/PgService.ts @@ -312,13 +312,14 @@ export class PgService { /** * Execute update or delete sql. * @param string updateSql the execute sql + * @param string values sql query parameters */ - updateBySql(updateSql) { + updateBySql(updateSql, values) { const _self = this; return new Promise((resolve, reject) => { logger.debug(`update sql is : ${updateSql}`); - _self.client.query(updateSql, [], (err, res) => { + _self.client.query(updateSql, values, (err, res) => { if (err) { logger.error('[INSERT ERROR] - ', err.message); reject(err); @@ -380,21 +381,16 @@ export class PgService { * @param unknown_type DB * @return unknown */ - getRowByPkOne(sql) { + getRowByPkOne(sql, values) { const _self = this; return new Promise((resolve, reject) => { - // Var sql = ` select ${column} from ${tablename} where ${pkColumn} = ${value} ` - _self.client.query(sql, (err, res) => { + _self.client.query(sql, values, (err, res) => { if (err) { reject(err); return; } - // Console.log( `The solution is: ${rows.length } ` ); - logger.debug(` the getRowByPkOne sql ${sql}`); - // (` the getRowByPkOne sql ${sql}`) - if (res && res.rows && res.rows[0]) { resolve(res.rows[0]); } else { @@ -490,18 +486,19 @@ export class PgService { * * * @param {*} sql + * @param {*} values * @returns * @memberof PgService */ - getRowsBySQlQuery(sql) { + getRowsBySQlQuery(sql, values) { const _self = this; return new Promise((resolve, reject) => { - _self.client.query(sql, (err, res) => { + _self.client.query(sql, values, (err, res) => { if (err) { reject(err); return; } - logger.debug(` the getRowsBySQlQuery ${sql}`); + logger.debug(` the getRowsBySQlQuery ${res.command}`); if (res && res.rows) { resolve(res.rows); @@ -516,12 +513,12 @@ export class PgService { * Search table by sql and it's not condition * * - * @param datatype sqlchareter the table name - * @param datatype condition the search condition,it is sorted by array. exp condition = array("id"=>"1"); + * @param datatype sqlcharacter the table name + * @param datatype values SQL query parameters * @param datatype limit the page limit. * */ - getRowsBySQlNoCondition(sqlcharacter, limit? ) : Promise{ + getRowsBySQlNoCondition(sqlcharacter, values, limit? ) : Promise{ /* eslint-disable */ const _self = this; return new Promise((resolve, reject) => { @@ -534,13 +531,13 @@ export class PgService { reject(null); return; } - _self.client.query(sql, (err, res) => { + _self.client.query(sql, values, (err, res) => { if (err) { reject(err); return; } - logger.debug(` the getRowsBySQlNoCondition ${sql}`); + logger.debug(` the getRowsBySQlNoCondition ${sql} ${values}`); if (res && res.rows) { resolve(res.rows); @@ -555,13 +552,13 @@ export class PgService { /** * 自动橱窗日志查找/评价历史记录查找 * @param unknown_type sql - * @param unknown_type DB + * @param unknown_type values * @return unknown */ - getRowsBySQlCase(sql) { + getRowsBySQlCase(sql, values) { const _self = this; return new Promise((resolve, reject) => { - _self.client.query(sql, (err, res) => { + _self.client.query(sql, values, (err, res) => { if (err) { reject(err); return; diff --git a/app/rest/dbroutes.ts b/app/rest/dbroutes.ts index a5f112951..52b0a4658 100644 --- a/app/rest/dbroutes.ts +++ b/app/rest/dbroutes.ts @@ -126,7 +126,7 @@ export function dbroutes(router: any, platform: any) { const channel_genesis_hash = req.params.channel_genesis_hash; const blockNum = parseInt(req.params.blocknum); let txid = parseInt(req.params.txid); - const orgs = requtil.orgsArrayToString(req.query); + const orgs = requtil.parseOrgsArray(req.query); const { from, to } = requtil.queryDatevalidator( req.query.from, req.query.to @@ -219,7 +219,7 @@ export function dbroutes(router: any, platform: any) { async (req: { params: { channel_genesis_hash: any; blocknum: string; }; query: { from: any; to: any; }; network: any; }, res: { send: (arg0: { status: number; rows: any; }) => any; }) => { const channel_genesis_hash = req.params.channel_genesis_hash; const blockNum = parseInt(req.params.blocknum); - const orgs = requtil.orgsArrayToString(req.query); + const orgs = requtil.parseOrgsArray(req.query); const { from, to } = requtil.queryDatevalidator( req.query.from, req.query.to diff --git a/app/rest/requestutils.ts b/app/rest/requestutils.ts index 70958c9bc..4b4b86cd0 100644 --- a/app/rest/requestutils.ts +++ b/app/rest/requestutils.ts @@ -89,8 +89,8 @@ function reqPayload(req: { params: any; query: any; body: any; }) { return requestPayload; } -const orgsArrayToString = function(reqQuery: { [key: string]: any; }) { - let temp = ''; +const parseOrgsArray = function(reqQuery: { [key: string]: any; }) { + if (reqQuery) { // eslint-disable-next-line spellcheck/spell-checker // workaround 'Type confusion through parameter tampering', see `https //lgtm dot com/rules/1506301137371 ` @@ -99,21 +99,15 @@ const orgsArrayToString = function(reqQuery: { [key: string]: any; }) { if (orgsStr) { const parsedReq = queryString.parse(orgsStr); if (parsedReq && parsedReq.orgs) { - const orgsArray = parsedReq.orgs.toString().split(','); - // format DB value for IN clause, ex: in ('a', 'b', 'c') - if (orgsArray) { - orgsArray.forEach((element, i) => { - temp += `'${element}'`; - if (orgsArray.length - 1 !== i) { - temp += ','; - } - }); - } + return Array.isArray(parsedReq) ? + parsedReq.orgs : + [parsedReq.orgs]; + } + else{ + return []; } } } - - return temp; }; const queryDatevalidator = function(from: string, to: string) { @@ -133,6 +127,6 @@ module.exports = { invalidRequest, notFound, reqPayload, - orgsArrayToString, + parseOrgsArray, queryDatevalidator };