first commit

This commit is contained in:
2024-09-18 10:17:07 +05:30
commit dfa85ede7e
31 changed files with 1147 additions and 0 deletions

View File

@@ -0,0 +1,216 @@
package net.ipksindia.dao
import model.TransactionRequest
import java.sql.Date
import java.sql.DriverManager
import java.sql.ResultSet
import java.util.*
class TransactionDao {
private val transactionRequestQuery = """
SELECT
txn_no,
TRIM(src_ac_no) AS src_ac_no,
TRIM(dest_ac_no) AS dest_ac_no,
ifsc_code,
txn_amt,
txn_date,
t.teller_id,
CASE
WHEN t.ifsc_code LIKE 'WBSC%' THEN 'FAILED'
ELSE 'RECEIVED'
END AS status,
SUBSTR(REGEXP_REPLACE(REGEXP_REPLACE(UPPER(beneficiary_name), '[^A-Z0-9 ]', ''), ' {2,}', ' '), 1, 35) AS beneficiary_name,
beneficiary_add,
t.pacs_id,
comm_txn_no,
comm_txn_amt,
dccb_code,
TO_NUMBER(cbs_br_code) AS br_code,
SUBSTR(REGEXP_REPLACE(REGEXP_REPLACE(UPPER(remm_name), '[^A-Z0-9 ]', ''), ' {2,}', ' '),1,35) AS remitter_name,
ipks_accno AS pacs_acc_no,
da.link_accno AS cbs_sb_acc_no,
'pacs_db' AS db_name
FROM neft_rtgs_txn t
JOIN dep_account da ON t.ipks_accno = da.key_1
WHERE
t.txn_date = (SELECT system_date FROM system_date)
AND t.STATUS = 'A'
AND t.bank_channel = 'SCB'
AND da.link_accno IS NOT NULL
""".trimIndent()
private val singleTransactionRequestQuery = """
SELECT
txn_no,
TRIM(src_ac_no) AS src_ac_no,
TRIM(dest_ac_no) AS dest_ac_no,
ifsc_code,
txn_amt,
txn_date,
t.teller_id,
CASE
WHEN t.ifsc_code LIKE 'WBSC%' THEN 'FAILED'
ELSE 'RECEIVED'
END AS status,
SUBSTR(REGEXP_REPLACE(REGEXP_REPLACE(UPPER(beneficiary_name), '[^A-Z0-9 ]', ''), ' {2,}', ' '), 1, 35) AS beneficiary_name,
beneficiary_add,
t.pacs_id,
comm_txn_no,
comm_txn_amt,
dccb_code,
TO_NUMBER(cbs_br_code) AS br_code,
SUBSTR(REGEXP_REPLACE(REGEXP_REPLACE(UPPER(remm_name), '[^A-Z0-9 ]', ''), ' {2,}', ' '),1,35) AS remitter_name,
ipks_accno AS pacs_acc_no,
da.link_accno AS cbs_sb_acc_no,
'pacs_db' AS db_name
FROM neft_rtgs_txn t
JOIN dep_account da ON t.ipks_accno = da.key_1
WHERE
t.txn_no = ?
""".trimIndent()
private val transactionUpdateQuery = """
INSERT INTO neft_rtgs_txn_queue (
txn_no,
src_ac_no,
dest_ac_no,
ifsc_code,
txn_amt,
txn_date,
teller_id,
status,
beneficiary_name,
beneficiary_add,
pacs_id,
comm_txn_no,
comm_txn_amt,
dccb_code,
br_code,
remitter_name,
cbs_queue_no,
pacs_acc_no,
cbs_queue_no2
) VALUES (
?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?
)
""".trimIndent()
fun updateSuccessTransaction(request: TransactionRequest, transferQueueNumber: String, neftQueueNumber: String) {
val dbUrl = getDatabaseUrl()
val (dbUser, dbPassword) = getUserCredentials()
DriverManager.getConnection(dbUrl, dbUser, dbPassword).use { connection ->
connection.prepareStatement(transactionUpdateQuery).also {
it.setString(1, request.transactionNumber)
it.setString(2, request.pacsCurrentAccountNumber)
it.setString(3, request.neftBeneficiaryAccountNumber)
it.setString(4, request.ifscCode)
it.setString(5, request.amount)
it.setDate(6, Date.valueOf(request.date))
it.setString(7, request.tellerId)
it.setString(8, "PROCESSED")
it.setString(9, request.beneficiaryName)
it.setString(10, request.beneficiaryAddress)
it.setString(11, request.pacsId)
it.setString(12, request.commissionTransactionNumber)
it.setString(13, request.commissionAmount)
it.setString(14, request.dccbCode)
it.setString(15, request.branchCode)
it.setString(16, request.remitterName)
it.setString(17, transferQueueNumber)
it.setString(18, request.pacsAccountNumber)
it.setString(19, neftQueueNumber)
}.use {
it.executeUpdate()
}
}
}
fun getTransactionRequests(): List<TransactionRequest> {
val transactionList: List<TransactionRequest>
val dbUrl = getDatabaseUrl()
val (dbUser, dbPassword) = getUserCredentials()
DriverManager.getConnection(dbUrl, dbUser, dbPassword).use { connection ->
connection.prepareStatement(transactionRequestQuery).executeQuery().use {
transactionList = mapToObject(it)
}
}
return transactionList
}
fun getTransactionRequest(transactionNumber: String): TransactionRequest? {
val dbUrl = getDatabaseUrl()
val (dbUser, dbPassword) = getUserCredentials()
return DriverManager.getConnection(dbUrl, dbUser, dbPassword).use { connection ->
connection.prepareStatement(singleTransactionRequestQuery).apply {
setString(1, transactionNumber)
}.executeQuery().use {
mapToObject(it).firstOrNull()
}
}
}
private fun getDatabaseUrl(): String {
val prop = loadProp()
val dbHost = getProp(prop, "DB_HOST")
val dbPort = getProp(prop, "DB_PORT")
val dbName = getProp(prop, "DB_NAME")
return "jdbc:oracle:thin:@$dbHost:$dbPort:$dbName"
}
private fun getUserCredentials(): Pair<String, String> {
val prop = loadProp()
val dbUser = getProp(prop, "DB_USER")
val dbPassword = getProp(prop, "DB_PASSWORD")
return Pair(dbUser, dbPassword)
}
private fun loadProp(): Properties {
val props = javaClass.classLoader.getResourceAsStream("application.properties").use {
Properties().apply { load(it) }
}
return props
}
private fun getProp(prop: Properties, key: String): String {
return prop.getProperty(key) ?: throw RuntimeException("property $prop not found")
}
private fun mapToObject(rs: ResultSet): List<TransactionRequest> {
val list = mutableListOf<TransactionRequest>()
while (rs.next()) {
val transactionRequest = TransactionRequest(
transactionNumber = rs.getString("txn_no"),
pacsCurrentAccountNumber = rs.getString("src_ac_no"),
neftBeneficiaryAccountNumber = rs.getString("dest_ac_no"),
ifscCode = rs.getString("ifsc_code"),
amount = rs.getString("txn_amt"),
date = rs.getDate("txn_date").toLocalDate(),
tellerId = rs.getString("teller_id"),
status = rs.getString("status"),
beneficiaryName = rs.getString("beneficiary_name"),
beneficiaryAddress = rs.getString("beneficiary_add"),
pacsId = rs.getString("pacs_id"),
commissionTransactionNumber = rs.getString("comm_txn_no"),
commissionAmount = rs.getString("comm_txn_amt"),
dccbCode = rs.getString("dccb_code"),
branchCode = rs.getString("br_Code"),
remitterName = rs.getString("remitter_name"),
pacsAccountNumber = rs.getString("pacs_acc_no"),
linkedCBSAccountNumber = rs.getString("cbs_sb_acc_no"),
)
list.add(transactionRequest)
}
return list
}
}