MySQL由于它本身的小巧和操作的高效, 在數(shù)據(jù)庫(kù)應(yīng)用中越來越多的被采用.我在開發(fā)一個(gè)P2P應(yīng)用的時(shí)候曾經(jīng)使用MySQL來保存P2P節(jié)點(diǎn),由于P2P的應(yīng)用中,結(jié)點(diǎn)數(shù)動(dòng)輒上萬個(gè),而且節(jié)點(diǎn)變化頻繁,因此一定要保持查詢和插入的高效.以下是我在使用過程中做的提高效率的三個(gè)有效的嘗試. 1. 使用statement進(jìn)行綁定查詢 2. 隨機(jī)的獲取記錄 3. 使用連接池管理連接.
MySQL由于它本身的小巧和操作的高效, 在數(shù)據(jù)庫(kù)應(yīng)用中越來越多的被采用.我在開發(fā)一個(gè)P2P應(yīng)用的時(shí)候曾經(jīng)使用MySQL來保存P2P節(jié)點(diǎn),由于P2P的應(yīng)用中,結(jié)點(diǎn)數(shù)動(dòng)輒上萬個(gè),而且節(jié)點(diǎn)變化頻繁,因此一定要保持查詢和插入的高效.以下是我在使用過程中做的提高效率的三個(gè)有效的嘗試. l 使用statement進(jìn)行綁定查詢 使用statement可以提前構(gòu)建查詢語法樹,在查詢時(shí)不再需要構(gòu)建語法樹就直接查詢.因此可以很好的提高查詢的效率. 這個(gè)方法適合于查詢條件固定但查詢非常頻繁的場(chǎng)合. 使用方法是: 綁定, 創(chuàng)建一個(gè)MYSQL_STMT變量,與對(duì)應(yīng)的查詢字符串綁定,字符串中的問號(hào)代表要傳入的變量,每個(gè)問號(hào)都必須指定一個(gè)變量. 查詢, 輸入每個(gè)指定的變量, 傳入MYSQL_STMT變量用可用的連接句柄執(zhí)行. 代碼如下: //1.綁定 bool CDBManager::BindInsertStmt(MYSQL * connecthandle) { //作插入操作的綁定 MYSQL_BIND insertbind[FEILD_NUM]; if(m_stInsertParam == NULL) m_stInsertParam = new CHostCacheTable; m_stInsertStmt = mysql_stmt_init(connecthandle); //構(gòu)建綁定字符串 char insertSQL[SQL_LENGTH]; strcpy(insertSQL, "insert into HostCache(SessionID, ChannelID, ISPType, " "ExternalIP, ExternalPort, InternalIP, InternalPort) " "values(?, ?, ?, ?, ?, ?, ?)"); mysql_stmt_prepare(m_stInsertStmt, insertSQL, strlen(insertSQL)); int param_count= mysql_stmt_param_count(m_stInsertStmt); if(param_count != FEILD_NUM) return false; //填充bind結(jié)構(gòu)數(shù)組, m_sInsertParam是這個(gè)statement關(guān)聯(lián)的結(jié)構(gòu)變量 memset(insertbind, 0, sizeof(insertbind));
insertbind[0].buffer_type = MYSQL_TYPE_STRING; insertbind[0].buffer_length = ID_LENGTH /* -1 */; insertbind[0].buffer = (char *)m_stInsertParam->sessionid; insertbind[0].is_null = 0; insertbind[0].length = 0; insertbind[1].buffer_type = MYSQL_TYPE_STRING; insertbind[1].buffer_length = ID_LENGTH /* -1 */; insertbind[1].buffer = (char *)m_stInsertParam->channelid; insertbind[1].is_null = 0; insertbind[1].length = 0; insertbind[2].buffer_type = MYSQL_TYPE_TINY; insertbind[2].buffer = (char *)&m_stInsertParam->ISPtype; insertbind[2].is_null = 0; insertbind[2].length = 0; insertbind[3].buffer_type = MYSQL_TYPE_LONG; insertbind[3].buffer = (char *)&m_stInsertParam->externalIP; insertbind[3].is_null = 0; insertbind[3].length = 0; insertbind[4].buffer_type = MYSQL_TYPE_SHORT; insertbind[4].buffer = (char *)&m_stInsertParam->externalPort; insertbind[4].is_null = 0; insertbind[4].length = 0; insertbind[5].buffer_type = MYSQL_TYPE_LONG; insertbind[5].buffer = (char *)&m_stInsertParam->internalIP; insertbind[5].is_null = 0; insertbind[5].length = 0; insertbind[6].buffer_type = MYSQL_TYPE_SHORT; insertbind[6].buffer = (char *)&m_stInsertParam->internalPort; insertbind[6].is_null = 0; insertbind[6].is_null = 0; //綁定 if (mysql_stmt_bind_param(m_stInsertStmt, insertbind))
return false; return true; } //2.查詢 bool CDBManager::InsertHostCache2(MYSQL * connecthandle, char * sessionid, char * channelid, int ISPtype, \ unsigned int eIP, unsigned short eport, unsigned int iIP, unsigned short iport) { //填充結(jié)構(gòu)變量m_sInsertParam strcpy(m_stInsertParam->sessionid, sessionid); strcpy(m_stInsertParam->channelid, channelid); m_stInsertParam->ISPtype = ISPtype; m_stInsertParam->externalIP = eIP; m_stInsertParam->externalPort = eport; m_stInsertParam->internalIP = iIP; m_stInsertParam->internalPort = iport; //執(zhí)行statement,性能瓶頸處 if(mysql_stmt_execute(m_stInsertStmt)) return false; return true; } l 隨機(jī)的獲取記錄 在某些數(shù)據(jù)庫(kù)的應(yīng)用中, 我們并不是要獲取所有的滿足條件的記錄,而只是要隨機(jī)挑選出滿足條件的記錄. 這種情況常見于數(shù)據(jù)業(yè)務(wù)的統(tǒng)計(jì)分析,從大容量數(shù)據(jù)庫(kù)中獲取小量的數(shù)據(jù)的場(chǎng)合. 有兩種方法可以做到 1. 常規(guī)方法,首先查詢出所有滿足條件的記錄,然后隨機(jī)的挑選出部分記錄.這種方法在滿足條件的記錄數(shù)很多時(shí)效果不理想. 2. 使用limit語法,先獲取滿足條件的記錄條數(shù), 然后在sql查詢語句中加入limit來限制只查詢滿足要求的一段記錄. 這種方法雖然要查詢兩次,但是在數(shù)據(jù)量大時(shí)反而比較高效. 示例代碼如下: //1.常規(guī)的方法 //性能瓶頸,10萬條記錄時(shí),執(zhí)行查詢140ms, 獲取結(jié)果集500ms,其余可忽略 int CDBManager::QueryHostCache(MYSQL* connecthandle, char * channelid, int ISPtype, CDBManager::CHostCacheTable * &hostcache) { char selectSQL[SQL_LENGTH]; memset(selectSQL, 0, sizeof(selectSQL)); sprintf(selectSQL,"select * from HostCache where ChannelID = ’%s’ and ISPtype = %d", channelid, ISPtype);
if(mysql_real_query(connecthandle, selectSQL, strlen(selectSQL)) != 0) //檢索 return 0; //獲取結(jié)果集 m_pResultSet = mysql_store_result(connecthandle); if(!m_pResultSet) //獲取結(jié)果集出錯(cuò) return 0; int iAllNumRows = (int)(mysql_num_rows(m_pResultSet)); ///<所有的搜索結(jié)果數(shù) //計(jì)算待返回的結(jié)果數(shù) int iReturnNumRows = (iAllNumRows <= RETURN_QUERY_HOST_NUM)? iAllNumRows:RETURN_QUERY_HOST_NUM; if(iReturnNumRows <= RETURN_QUERY_HOST_NUM) { //獲取逐條記錄 for(int i = 0; i<iReturnNumRows; i++) { //獲取逐個(gè)字段 m_Row = mysql_fetch_row(m_pResultSet); if(m_Row[0] != NULL) strcpy(hostcache[i].sessionid, m_Row[0]); if(m_Row[1] != NULL) strcpy(hostcache[i].channelid, m_Row[1]); if(m_Row[2] != NULL) hostcache[i].ISPtype = atoi(m_Row[2]);
if(m_Row[3] != NULL) hostcache[i].externalIP = atoi(m_Row[3]); if(m_Row[4] != NULL) hostcache[i].externalPort = atoi(m_Row[4]); if(m_Row[5] != NULL) hostcache[i].internalIP = atoi(m_Row[5]); if(m_Row[6] != NULL) hostcache[i].internalPort = atoi(m_Row[6]); } } else { //隨機(jī)的挑選指定條記錄返回 int iRemainder = iAllNumRows%iReturnNumRows; ///<余數(shù) int iQuotient = iAllNumRows/iReturnNumRows; ///<商 int iStartIndex = rand()%(iRemainder + 1); ///<開始下標(biāo) //獲取逐條記錄 for(int iSelectedIndex = 0; iSelectedIndex < iReturnNumRows; iSelectedIndex++)
{ mysql_data_seek(m_pResultSet, iStartIndex + iQuotient * iSelectedIndex); m_Row = mysql_fetch_row(m_pResultSet); if(m_Row[0] != NULL) strcpy(hostcache[iSelectedIndex].sessionid, m_Row[0]); if(m_Row[1] != NULL) strcpy(hostcache[iSelectedIndex].channelid, m_Row[1]); if(m_Row[2] != NULL) hostcache[iSelectedIndex].ISPtype = atoi(m_Row[2]); if(m_Row[3] != NULL) hostcache[iSelectedIndex].externalIP = atoi(m_Row[3]); if(m_Row[4] != NULL) hostcache[iSelectedIndex].externalPort = atoi(m_Row[4]); if(m_Row[5] != NULL) hostcache[iSelectedIndex].internalIP = atoi(m_Row[5]); if(m_Row[6] != NULL) hostcache[iSelectedIndex].internalPort = atoi(m_Row[6]); } } //釋放結(jié)果集內(nèi)容 mysql_free_result(m_pResultSet); return iReturnNumRows; } //2.使用limit版 int CDBManager::QueryHostCache(MYSQL * connecthandle, char * channelid, unsigned int myexternalip, int ISPtype, CHostCacheTable * hostcache) { //首先獲取滿足結(jié)果的記錄條數(shù),再使用limit隨機(jī)選擇指定條記錄返回 MYSQL_ROW row; MYSQL_RES * pResultSet; char selectSQL[SQL_LENGTH]; memset(selectSQL, 0, sizeof(selectSQL)); sprintf(selectSQL,"select count(*) from HostCache where ChannelID = ’%s’ and ISPtype = %d", channelid, ISPtype); if(mysql_real_query(connecthandle, selectSQL, strlen(selectSQL)) != 0) //檢索 return 0; pResultSet = mysql_store_result(connecthandle); if(!pResultSet) return 0; row = mysql_fetch_row(pResultSet); int iAllNumRows = atoi(row[0]); mysql_free_result(pResultSet); //計(jì)算待取記錄的上下范圍 int iLimitLower = (iAllNumRows <= RETURN_QUERY_HOST_NUM)? 0:(rand()%(iAllNumRows - RETURN_QUERY_HOST_NUM)); int iLimitUpper = (iAllNumRows <= RETURN_QUERY_HOST_NUM)? iAllNumRows:(iLimitLower + RETURN_QUERY_HOST_NUM); //計(jì)算待返回的結(jié)果數(shù) int iReturnNumRows = (iAllNumRows <= RETURN_QUERY_HOST_NUM)? iAllNumRows:RETURN_QUERY_HOST_NUM; //使用limit作查詢 sprintf(selectSQL,"select SessionID, ExternalIP, ExternalPort, InternalIP, InternalPort " "from HostCache where ChannelID = ’%s’ and ISPtype = %d limit %d, %d" , channelid, ISPtype, iLimitLower, iLimitUpper); if(mysql_real_query(connecthandle, selectSQL, strlen(selectSQL)) != 0) //檢索 return 0; pResultSet = mysql_store_result(connecthandle); if(!pResultSet) return 0; //獲取逐條記錄 for(int i = 0; i<iReturnNumRows; i++) { //獲取逐個(gè)字段 row = mysql_fetch_row(pResultSet); if(row[0] != NULL) strcpy(hostcache[i].sessionid, row[0]); if(row[1] != NULL) hostcache[i].externalIP = atoi(row[1]); if(row[2] != NULL) hostcache[i].externalPort = atoi(row[2]); if(row[3] != NULL) hostcache[i].internalIP = atoi(row[3]); if(row[4] != NULL) hostcache[i].internalPort = atoi(row[4]); } //釋放結(jié)果集內(nèi)容 mysql_free_result(pResultSet); return iReturnNumRows; } l 使用連接池管理連接. 在有大量節(jié)點(diǎn)訪問的數(shù)據(jù)庫(kù)設(shè)計(jì)中,經(jīng)常要使用到連接池來管理所有的連接. 一般方法是:建立兩個(gè)連接句柄隊(duì)列,空閑的等待使用的隊(duì)列和正在使用的隊(duì)列. 當(dāng)要查詢時(shí)先從空閑隊(duì)列中獲取一個(gè)句柄,插入到正在使用的隊(duì)列,再用這個(gè)句柄做數(shù)據(jù)庫(kù)操作,完畢后一定要從使用隊(duì)列中刪除,再插入到空閑隊(duì)列. 設(shè)計(jì)代碼如下: //定義句柄隊(duì)列 typedef std::list<MYSQL *> CONNECTION_HANDLE_LIST; typedef std::list<MYSQL *>::iterator CONNECTION_HANDLE_LIST_IT; //連接數(shù)據(jù)庫(kù)的參數(shù)結(jié)構(gòu) class CDBParameter { public: char *host; ///<主機(jī)名 char *user; ///<用戶名 char *password; ///<密碼 char *database; ///<數(shù)據(jù)庫(kù)名 unsigned int port; ///<端口,一般為0 const char *unix_socket; ///<套接字,一般為NULL unsigned int client_flag; ///<一般為0 }; //創(chuàng)建兩個(gè)隊(duì)列 CONNECTION_HANDLE_LIST m_lsBusyList; ///<正在使用的連接句柄 CONNECTION_HANDLE_LIST m_lsIdleList; ///<未使用的連接句柄 //所有的連接句柄先連上數(shù)據(jù)庫(kù),加入到空閑隊(duì)列中,等待使用. bool CDBManager::Connect(char * host /* = "localhost" */, char * user /* = "chenmin" */, \ char * password /* = "chenmin" */, char * database /* = "HostCache" */) { CDBParameter * lpDBParam = new CDBParameter(); lpDBParam->host = host; lpDBParam->user = user; lpDBParam->password = password; lpDBParam->database = database; lpDBParam->port = 0; lpDBParam->unix_socket = NULL; lpDBParam->client_flag = 0; try { //連接 for(int index = 0; index < CONNECTION_NUM; index++) { MYSQL * pConnectHandle = mysql_init((MYSQL*) 0); //初始化連接句柄 if(!mysql_real_connect(pConnectHandle, lpDBParam->host, lpDBParam->user, lpDBParam->password,\ lpDBParam->database,lpDBParam->port,lpDBParam->unix_socket,lpDBParam->client_fla)) return false; //加入到空閑隊(duì)列中 m_lsIdleList.push_back(pConnectHandle); } } catch(...) { return false; } return true; } //提取一個(gè)空閑句柄供使用 MYSQL * CDBManager::GetIdleConnectHandle() { MYSQL * pConnectHandle = NULL; m_ListMutex.acquire(); if(m_lsIdleList.size()) { pConnectHandle = m_lsIdleList.front(); m_lsIdleList.pop_front(); m_lsBusyList.push_back(pConnectHandle); } else //特殊情況,閑隊(duì)列中為空,返回為空 { pConnectHandle = 0; } m_ListMutex.release(); return pConnectHandle; } //從使用隊(duì)列中釋放一個(gè)使用完畢的句柄,插入到空閑隊(duì)列 void CDBManager::SetIdleConnectHandle(MYSQL * connecthandle) { m_ListMutex.acquire(); m_lsBusyList.remove(connecthandle); m_lsIdleList.push_back(connecthandle); m_ListMutex.release(); } //使用示例,首先獲取空閑句柄,利用這個(gè)句柄做真正的操作,然后再插回到空閑隊(duì)列 bool CDBManager::DeleteHostCacheBySessionID(char * sessionid) { MYSQL * pConnectHandle = GetIdleConnectHandle(); if(!pConnectHandle) return 0; bool bRet = DeleteHostCacheBySessionID(pConnectHandle, sessionid); SetIdleConnectHandle(pConnectHandle); return bRet; } //傳入空閑的句柄,做真正的刪除操作 bool CDBManager::DeleteHostCacheBySessionID(MYSQL * connecthandle, char * sessionid) { char deleteSQL[SQL_LENGTH]; memset(deleteSQL, 0, sizeof(deleteSQL)); sprintf(deleteSQL,"delete from HostCache where SessionID = ’%s’", sessionid); if(mysql_query(connecthandle,deleteSQL) != 0) //刪除 return false; return true; }
|