Great performance increase on transaction queries
This will address an issue with database including a lot of transactions. No more nested queries that put unwanted strain on a DB. Address #536
This commit is contained in:
parent
b5e12923fd
commit
9e1f424742
@ -227,31 +227,15 @@ class Transaction {
|
|||||||
public function getLockedBalance() {
|
public function getLockedBalance() {
|
||||||
$this->debug->append("STA " . __METHOD__, 4);
|
$this->debug->append("STA " . __METHOD__, 4);
|
||||||
$stmt = $this->mysqli->prepare("
|
$stmt = $this->mysqli->prepare("
|
||||||
SELECT ROUND(IFNULL(t1.credit, 0) - IFNULL(t2.debit, 0) - IFNULL(t3.other, 0), 8) AS balance
|
SELECT
|
||||||
FROM
|
ROUND((
|
||||||
(
|
SUM( IF( ( t.type IN ('Credit','Bonus') OR t.type = 'Credit_PPS') AND b.confirmations >= ?, t.amount, 0 ) ) -
|
||||||
SELECT sum(t.amount) AS credit
|
SUM( IF( t.type IN ('Debit_MP', 'Debit_AP'), t.amount, 0 ) ) -
|
||||||
FROM $this->table AS t
|
SUM( IF( ( t.type IN ('Donation','Fee') AND b.confirmations >= ? ) OR ( t.type IN ('Donation_PPS', 'Fee_PPS', 'TXFee') ), t.amount, 0 ) )
|
||||||
LEFT JOIN " . $this->block->getTableName() . " AS b ON t.block_id = b.id
|
), 8) AS balance
|
||||||
WHERE (
|
FROM $this->table AS t
|
||||||
( t.type IN ('Credit','Bonus') AND b.confirmations >= ? ) OR
|
LEFT JOIN blocks AS b
|
||||||
( t.type = 'Credit_PPS' )
|
ON t.block_id = b.id");
|
||||||
)
|
|
||||||
) AS t1,
|
|
||||||
(
|
|
||||||
SELECT sum(t.amount) AS debit
|
|
||||||
FROM $this->table AS t
|
|
||||||
WHERE t.type IN ('Debit_MP', 'Debit_AP')
|
|
||||||
) AS t2,
|
|
||||||
(
|
|
||||||
SELECT sum(t.amount) AS other
|
|
||||||
FROM " . $this->table . " AS t
|
|
||||||
LEFT JOIN " . $this->block->getTableName() . " AS b ON t.block_id = b.id
|
|
||||||
WHERE (
|
|
||||||
( t.type IN ('Donation','Fee') AND b.confirmations >= ? ) OR
|
|
||||||
t.type IN ('Donation_PPS','Fee_PPS','TXFee')
|
|
||||||
)
|
|
||||||
) AS t3");
|
|
||||||
if ($this->checkStmt($stmt) && $stmt->bind_param('ii', $this->config['confirmations'], $this->config['confirmations']) && $stmt->execute() && $stmt->bind_result($dBalance) && $stmt->fetch())
|
if ($this->checkStmt($stmt) && $stmt->bind_param('ii', $this->config['confirmations'], $this->config['confirmations']) && $stmt->execute() && $stmt->bind_result($dBalance) && $stmt->fetch())
|
||||||
return $dBalance;
|
return $dBalance;
|
||||||
// Catchall
|
// Catchall
|
||||||
@ -269,85 +253,27 @@ class Transaction {
|
|||||||
$this->debug->append("STA " . __METHOD__, 4);
|
$this->debug->append("STA " . __METHOD__, 4);
|
||||||
$stmt = $this->mysqli->prepare("
|
$stmt = $this->mysqli->prepare("
|
||||||
SELECT
|
SELECT
|
||||||
ROUND(IFNULL(t1.credit, 0) - IFNULL(t2.debit, 0) - IFNULL(t3.other, 0), 8) AS confirmed,
|
ROUND((
|
||||||
ROUND(IFNULL(t4.credit, 0) - IFNULL(t5.other, 0), 8) AS unconfirmed,
|
SUM( IF( ( t.type IN ('Credit','Bonus') OR t.type = 'Credit_PPS') AND b.confirmations >= ?, t.amount, 0 ) ) -
|
||||||
ROUND(IFNULL(t6.credit, 0) - IFNULL(t7.other, 0), 8) AS orphaned
|
SUM( IF( t.type IN ('Debit_MP', 'Debit_AP'), t.amount, 0 ) ) -
|
||||||
FROM
|
SUM( IF( ( t.type IN ('Donation','Fee') AND b.confirmations >= ? ) OR ( t.type IN ('Donation_PPS', 'Fee_PPS', 'TXFee') ), t.amount, 0 ) )
|
||||||
(
|
), 8) AS confirmed,
|
||||||
SELECT sum(t.amount) AS credit
|
ROUND((
|
||||||
FROM $this->table AS t
|
SUM( IF( t.type IN ('Credit','Bonus') AND b.confirmations < ? AND b.confirmations >= 0, t.amount, 0 ) ) -
|
||||||
LEFT JOIN " . $this->block->getTableName() . " AS b ON t.block_id = b.id
|
SUM( IF( t.type IN ('Donation','Fee') AND b.confirmations < ? AND b.confirmations >= 0, t.amount, 0 ) )
|
||||||
WHERE
|
), 8) AS unconfirmed,
|
||||||
(
|
ROUND((
|
||||||
( t.type IN ('Credit','Bonus') AND b.confirmations >= ? ) OR
|
SUM( IF( t.type IN ('Credit','Bonus') AND b.confirmations = -1, t.amount, 0) ) -
|
||||||
( t.type = 'Credit_PPS' )
|
SUM( IF( t.type IN ('Donation','Fee') AND b.confirmations = -1, t.amount, 0) )
|
||||||
)
|
), 8) AS orphaned
|
||||||
AND t.account_id = ?
|
FROM transactions AS t
|
||||||
) AS t1,
|
LEFT JOIN blocks AS b
|
||||||
(
|
ON t.block_id = b.id
|
||||||
SELECT sum(t.amount) AS debit
|
AND t.account_id = ?
|
||||||
FROM $this->table AS t
|
|
||||||
WHERE t.type IN ('Debit_MP', 'Debit_AP')
|
|
||||||
AND t.account_id = ?
|
|
||||||
) AS t2,
|
|
||||||
(
|
|
||||||
SELECT sum(t.amount) AS other
|
|
||||||
FROM $this->table AS t
|
|
||||||
LEFT JOIN " . $this->block->getTableName() . " AS b ON t.block_id = b.id
|
|
||||||
WHERE
|
|
||||||
(
|
|
||||||
( t.type IN ('Donation','Fee') AND b.confirmations >= ? ) OR
|
|
||||||
( t.type IN ('Donation_PPS', 'Fee_PPS', 'TXFee') )
|
|
||||||
)
|
|
||||||
AND t.account_id = ?
|
|
||||||
) AS t3,
|
|
||||||
(
|
|
||||||
SELECT sum(t.amount) AS credit
|
|
||||||
FROM $this->table AS t
|
|
||||||
LEFT JOIN " . $this->block->getTableName() . " AS b ON t.block_id = b.id
|
|
||||||
WHERE
|
|
||||||
t.type IN ('Credit','Bonus') AND b.confirmations < ? AND b.confirmations >= 0
|
|
||||||
AND t.account_id = ?
|
|
||||||
) AS t4,
|
|
||||||
(
|
|
||||||
SELECT sum(t.amount) AS other
|
|
||||||
FROM $this->table AS t
|
|
||||||
LEFT JOIN " . $this->block->getTableName() . " AS b ON t.block_id = b.id
|
|
||||||
WHERE
|
|
||||||
(
|
|
||||||
t.type IN ('Donation','Fee') AND b.confirmations < ? AND b.confirmations >= 0
|
|
||||||
)
|
|
||||||
AND t.account_id = ?
|
|
||||||
) AS t5,
|
|
||||||
(
|
|
||||||
SELECT sum(t.amount) AS credit
|
|
||||||
FROM $this->table AS t
|
|
||||||
LEFT JOIN " . $this->block->getTableName() . " AS b ON t.block_id = b.id
|
|
||||||
WHERE
|
|
||||||
t.type IN ('Credit','Bonus') AND b.confirmations = -1
|
|
||||||
AND t.account_id = ?
|
|
||||||
) AS t6,
|
|
||||||
(
|
|
||||||
SELECT sum(t.amount) AS other
|
|
||||||
FROM $this->table AS t
|
|
||||||
LEFT JOIN " . $this->block->getTableName() . " AS b ON t.block_id = b.id
|
|
||||||
WHERE
|
|
||||||
(
|
|
||||||
t.type IN ('Donation','Fee') AND b.confirmations = -1
|
|
||||||
)
|
|
||||||
AND t.account_id = ?
|
|
||||||
) AS t7
|
|
||||||
");
|
");
|
||||||
if ($this->checkStmt($stmt)) {
|
if ($this->checkStmt($stmt) && $stmt->bind_param("iiiii", $this->config['confirmations'], $this->config['confirmations'], $this->config['confirmations'], $this->config['confirmations'], $account_id) && $stmt->execute() && $result = $stmt->get_result())
|
||||||
$stmt->bind_param("iiiiiiiiiii", $this->config['confirmations'], $account_id, $account_id, $this->config['confirmations'], $account_id, $this->config['confirmations'], $account_id, $this->config['confirmations'], $account_id, $account_id, $account_id);
|
|
||||||
if (!$stmt->execute()) {
|
|
||||||
$this->debug->append("Unable to execute statement: " . $stmt->error);
|
|
||||||
$this->setErrorMessage("Fetching balance failed");
|
|
||||||
}
|
|
||||||
$result = $stmt->get_result();
|
|
||||||
$stmt->close();
|
|
||||||
return $result->fetch_assoc();
|
return $result->fetch_assoc();
|
||||||
}
|
$this->debug->append('Failed to fetch users balance: ' . $this->mysqli->error);
|
||||||
return false;
|
return false;
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|||||||
Loading…
Reference in New Issue
Block a user