access类似DAvg功能的扩展函数-求多个排序数值的平均值
- 2019-10-14 15:30:00
- Allen Browne 翻译
- 4362
下面分享一个名为EAvg()函数,该函数是DAvg函数的扩展,可以从该字段中获取TOP(或百分比)的平均值。 甚至可以指定其他字段进行排序
Public Function EAvg(strExpr As String, strDomain As String, Optional strCriteria As String, _ Optional dblTop As Double, Optional strOrderBy As String) As Variant On Error GoTo Err_Error 'Purpose: Extended replacement for DAvg(). 'Author: Allen Browne (allen@allenbrowne.com), November 2006. 'Requires: Access 2000 and later. 'Return: Average of the field in the domain. Null on error. 'Arguments: strExpr = the field name to average. ' strDomain = the table or query to use. ' strCriteria = WHERE clause limiting the records. ' dblTop = TOP number of records to average. Ignored if zero or negative. ' Treated as a percent if less than 1. ' strOrderBy = ORDER BY clause. 'Note: The ORDER BY clause defaults to the expression field DESC if none is provided. ' However, if there is a tie, Access returns more than the TOP number specified, ' unless you include the primary key in the ORDER BY clause. See example below. 'Example: Return the average of the 4 highest quantities in tblInvoiceDetail: ' EAvg("Quantity", "tblInvoiceDetail",,4, "Quantity DESC, InvoiceDetailID") Dim rs As DAO.Recordset Dim strSql As String Dim lngTopAsPercent As Long EAvg = Null 'Initialize to null. lngTopAsPercent = 100# * dblTop If lngTopAsPercent > 0& Then 'There is a TOP predicate If lngTopAsPercent < 100& Then 'Less than 1, so treat as percent. strSql = "SELECT Avg(" & strExpr & ") AS TheAverage " & vbCrLf & _ "FROM (SELECT TOP " & lngTopAsPercent & " PERCENT " & strExpr Else 'More than 1, so treat as count. strSql = "SELECT Avg(" & strExpr & ") AS TheAverage " & vbCrLf & _ "FROM (SELECT TOP " & CLng(dblTop) & " " & strExpr End If strSql = strSql & " " & vbCrLf & " FROM " & strDomain & " " & vbCrLf & _ " WHERE (" & strExpr & " Is Not Null)" If strCriteria <> vbNullString Then strSql = strSql & vbCrLf & " AND (" & strCriteria & ") " End If If strOrderBy <> vbNullString Then strSql = strSql & vbCrLf & " ORDER BY " & strOrderBy & ") AS MySubquery;" Else strSql = strSql & vbCrLf & " ORDER BY " & strExpr & " DESC) AS MySubquery;" End If Else 'There is no TOP predicate (so we also ignore any ORDER BY.) strSql = "SELECT Avg(" & strExpr & ") AS TheAverage " & vbCrLf & _ "FROM " & strDomain & " " & vbCrLf & "WHERE (" & strExpr & " Is Not Null)" If strCriteria <> vbNullString Then strSql = strSql & vbCrLf & " AND (" & strCriteria & ")" End If strSql = strSql & ";" End If Set rs = DBEngine(0)(0).OpenRecordset(strSql) If rs.RecordCount > 0& Then EAvg = rs!TheAverage End If rs.Close Exit_Handler: Set rs = Nothing Exit Function Err_Error: MsgBox "Error " & Err.Number & ": " & Err.Description, , "EAvg()" Resume Exit_Handler End Function
Eavg函数排序参数默认是降序,取前面2位后再求平均值,如下图。
Access数据库自身
- office课程播放地址及课程明细
- Excel Word PPT Access VBA等Office技巧学习平台
- 将( .accdb) 文件格式数据库转换为早期版本(.mdb)的文件格式
- 将早期的数据库文件格式(.mdb)转换为 (.accdb) 文件格式
- KB5002984:配置 Jet Red Database Engine 数据库引擎和访问连接引擎以阻止对远程数据库的访问(remote table)
- Access 365 /Access 2019 数据库中哪些函数功能和属性被沙箱模式阻止(如未启动宏时)
- Access Runtime(运行时)最全的下载(2007 2010 2013 2016 2019 Access 365)
Access Activex第三方控件
- Activex控件或Dll 在某些电脑无法正常注册的解决办法(regsvr32注册时卡住)
- office使用部分控件时提示“您没有使用该ActiveX控件许可的问题”的解决方法
- RTF文件(富文本格式)的一些解析
- Access树控件(treeview) 64位Office下出现横向滚动条不会自动定位的解决办法
- Access中国树控件 在win10电脑 节点行间距太小的解决办法
- EXCEL 2019 64位版(Office 2019 64位)早就支持64位Treeview 树控件 ListView列表等64位MSCOMMCTL.OCX控件下载
- VBA或VB6调用WebService(直接Post方式)并解析返回的XML
Access ADP Sql Server等
- 早期PB程序连接Sqlserver出现错误
- MMC 不能打开文件C:/Program Files/Microsoft SQL Server/80/Tools/Binn/SQL Server Enterprise Manager.MSC 可能是由于文件不存在,不是一个MMC控制台,或者用后来的MMC版
- sql server连接不了的解决办法
- localhost与127.0.0.1区别
- Roych的浅谈数据库开发系列(Sql Server)
- sqlserver 自动备份对备份目录没有存取权限的解决办法
- 安装Sql server 2005 express 和SQLServer2005 Express版企业管理器 SQLServer2005_SSMSEE
文章分类
联系我们
联系人: | 王先生 |
---|---|
Email: | 18449932@qq.com |
QQ: | 18449932 |
微博: | officecn01 |