access類似DCount功能的擴(kuò)展函數(shù)-統(tǒng)計(jì)不同值的數(shù)量
- 2019-10-11 16:28:00
- Allen Browne 翻譯
- 6533
access中,使用 DCount 函數(shù)可以統(tǒng)計(jì)特定記錄集內(nèi)的總數(shù)。但是DCount還有些不足:
1. 內(nèi)置函數(shù)DCount()無(wú)法計(jì)算不同值的數(shù)量;
2. Access中的域聚合函數(shù)效率低下。
這里給出一個(gè)自定義的Ecount函數(shù),它提供了一個(gè)額外的參數(shù),可以計(jì)算不同的值
Public Function ECount(Expr As String, Domain As String, Optional Criteria As String, Optional bCountDistinct As Boolean) As Variant On Error GoTo Err_Handler 'Purpose: Enhanced DCount() function, with the ability to count distinct. 'Return: Number of records. Null on error. 'Arguments: Expr = name of the field to count. Use square brackets if the name contains a space. ' Domain = name of the table or query. ' Criteria = any restrictions. Can omit. ' bCountDistinct = True to return the number of distinct values in the field. Omit for normal count. 'Notes: Nulls are excluded (whether distinct count or not.) ' Use "*" for Expr if you want to count the nulls too. ' You cannot use "*" if bCountDistinct is True. 'Examples: Number of customers who have a region: ECount("Region", "Customers") ' Number of customers who have no region: ECount("*", "Customers", "Region Is Null") ' Number of distinct regions: ECount("Region", "Customers", ,True) Dim db As DAO.Database Dim rs As DAO.Recordset Dim strSql As String 'Initialize to return Null on error. ECount = Null Set db = DBEngine(0)(0) If bCountDistinct Then 'Count distinct values. If Expr <> "*" Then 'Cannot count distinct with the wildcard. strSql = "SELECT " & Expr & " FROM " & Domain & " WHERE (" & Expr & " Is Not Null)" If Criteria <> vbNullString Then strSql = strSql & " AND (" & Criteria & ")" End If strSql = strSql & " GROUP BY " & Expr & ";" Set rs = db.OpenRecordset(strSql) If rs.RecordCount > 0& Then rs.MoveLast End If ECount = rs.RecordCount 'Return the number of distinct records. rs.Close End If Else 'Normal count. strSql = "SELECT Count(" & Expr & ") AS TheCount FROM " & Domain If Criteria <> vbNullString Then strSql = strSql & " WHERE " & Criteria End If Set rs = db.OpenRecordset(strSql) If rs.RecordCount > 0& Then ECount = rs!TheCount 'Return the count. End If rs.Close End If Exit_Handler: Set rs = Nothing Set db = Nothing Exit Function Err_Handler: MsgBox Err.Description, vbExclamation, "ECount Error " & Err.Number Resume Exit_Handler End Function
如下圖,可以計(jì)算字段中不重復(fù)的值,如果參數(shù)為false,即功能跟Dcount是一樣的。
分享
Access數(shù)據(jù)庫(kù)自身
- office課程播放地址及課程明細(xì)
- Excel Word PPT Access VBA等Office技巧學(xué)習(xí)平臺(tái)
- 將( .accdb) 文件格式數(shù)據(jù)庫(kù)轉(zhuǎn)換為早期版本(.mdb)的文件格式
- 將早期的數(shù)據(jù)庫(kù)文件格式(.mdb)轉(zhuǎn)換為 (.accdb) 文件格式
- KB5002984:配置 Jet Red Database Engine 數(shù)據(jù)庫(kù)引擎和訪問(wèn)連接引擎以阻止對(duì)遠(yuǎn)程數(shù)據(jù)庫(kù)的訪問(wèn)(remote table)
- Access 365 /Access 2019 數(shù)據(jù)庫(kù)中哪些函數(shù)功能和屬性被沙箱模式阻止(如未啟動(dòng)宏時(shí))
- Access Runtime(運(yùn)行時(shí))最全的下載(2007 2010 2013 2016 2019 Access 365)
Access VBA函數(shù)模塊
- access vba代碼太長(zhǎng),換行,分行的寫(xiě)法
- VB6 VBA Access真正可用并且完美支持中英文的 URLEncode 與 URLDecode 函數(shù)源碼
- 自定義VB中的urlencode函數(shù),將URL中特殊部分進(jìn)行編碼
- Access 函數(shù)簡(jiǎn)化串接sql字符串,減少符號(hào)導(dǎo)致的書(shū)寫(xiě)錯(cuò)誤
- vba完全關(guān)閉IE瀏覽器及調(diào)用IE瀏覽器的簡(jiǎn)單應(yīng)用
- 利用FollowHyperlink方法打開(kāi)超鏈接提示“無(wú)法下載您要求的信息”的解決方案
- 在access中用代碼打開(kāi)文本框中超鏈接地址
Access Activex第三方控件
- Activex控件或Dll 在某些電腦無(wú)法正常注冊(cè)的解決辦法(regsvr32注冊(cè)時(shí)卡住)
- office使用部分控件時(shí)提示“您沒(méi)有使用該ActiveX控件許可的問(wèn)題”的解決方法
- RTF文件(富文本格式)的一些解析
- Access樹(shù)控件(treeview) 64位Office下出現(xiàn)橫向滾動(dòng)條不會(huì)自動(dòng)定位的解決辦法
- Access中國(guó)樹(shù)控件 在win10電腦 節(jié)點(diǎn)行間距太小的解決辦法
- EXCEL 2019 64位版(Office 2019 64位)早就支持64位Treeview 樹(shù)控件 ListView列表等64位MSCOMMCTL.OCX控件下載
- VBA或VB6調(diào)用WebService(直接Post方式)并解析返回的XML
Access ADP Sql Server等
- 早期PB程序連接Sqlserver出現(xiàn)錯(cuò)誤
- MMC 不能打開(kāi)文件C:/Program Files/Microsoft SQL Server/80/Tools/Binn/SQL Server Enterprise Manager.MSC 可能是由于文件不存在,不是一個(gè)MMC控制臺(tái),或者用后來(lái)的MMC版
- sql server連接不了的解決辦法
- localhost與127.0.0.1區(qū)別
- Roych的淺談數(shù)據(jù)庫(kù)開(kāi)發(fā)系列(Sql Server)
- sqlserver 自動(dòng)備份對(duì)備份目錄沒(méi)有存取權(quán)限的解決辦法
- 安裝Sql server 2005 express 和SQLServer2005 Express版企業(yè)管理器 SQLServer2005_SSMSEE
Access 行業(yè)應(yīng)用開(kāi)發(fā)
- 金蝶KIS旗艦版 登錄時(shí)“類型不匹配”
- access行業(yè)交流QQ群-部分行業(yè)交流群(倉(cāng)庫(kù) 人事 工資 考勤 CRM HRM MRP ERP 等)
- access垃圾分類數(shù)據(jù)庫(kù)
- Office提高企業(yè)辦公管理效率
- Access交流網(wǎng)Acccess通用開(kāi)發(fā)平臺(tái)樹(shù)導(dǎo)航出錯(cuò)的解決辦法
- Access交流網(wǎng)Access通用開(kāi)發(fā)平臺(tái)的使用幫助教程及FAQ
- Access采購(gòu)倉(cāng)庫(kù)系統(tǒng)作品源代碼
文章分類
聯(lián)系我們
聯(lián)系人: | 王先生 |
---|---|
Email: | 18449932@qq.com |
QQ: | 18449932 |
微博: | officecn01 |