Access开发培训
网站公告
·Access专家课堂QQ群号:151711184    ·Access快速开发平台下载地址及教程    ·欢迎加入Access专家课堂微信群!    ·如何快速搜索本站文章|示例|资料    
您的位置: 首页 > 技术文章 > 综合其它

excel表间sql语句运算

时 间:2018-06-08 15:31:06
作 者:萤火虫   ID:66752  城市:大理
摘 要:excel表间sql语句运算
正 文:

excel工作表中数据存放,如同数据库一般模样,以excel2010为例

1,插入一张工作表,选择数据选项卡,单击“获取外部数据”组中“现有连接”,弹出“现有连接”对 话框   单     击“浏览更多”按钮,在弹出的“选取数据源”对话框中,点选磁盘中的excel文件(本文件也行)

2,单击“选择表格”对话框中的“确定”按钮,(任选一张工作表也行)
3,在弹出的“导入数据”对话框中,单选模式有 A:表  B:数据透视表 C:数据透视图与数据透视表
4,单击“属性”按钮。弹出“连接属性”对话框,切换到“定义卡”选项,将命令文本修改为:
   select "期初",规格型号,机器号,数量,0 as 数量3, 0 as 数量2, 金额,0 as 金额3, 0 as 金额2  from     [期    初$]  union  all  select "入库",规格型号,机器号, 0 as 数量2, 数量,0 as 数量3, 0 as 金额2,    金额,0 as    金额3 from  [入库$]  union  all  select "出库",规格型号,机器号, 0 as 数量3, 0 as 数   量2,数量, 0 as   金额3, 0 as 金额2,金额 from [出库$]

5,详见上传收支存工作簿文件,数据透视表选项展示数据




附   件:

点击下载此示例


类似sql语句“命令文本”参照举例如




Select *
FROM [城市编码$]
Where 编码 IN
(Select 编码 
FROM [城市编码$]
GROUP BY 编码
HAVING COUNT(编码)=1)

Select 存货编码,ROUND(MIN(单价),2) AS 单价
FROM [存货价格$]
GROUP BY 存货编码

Select IIF(得分<21,"1:20",IIF(得分<41,"21:40",IIF(得分<61,"41:60",IIF(得分<81,"61:80","81:100")))) AS 范围,
COUNT(得分) AS 个数
FROM [物理成绩$]
GROUP BY IIF(得分<21,"1:20",IIF(得分<41,"21:40",IIF(得分<61,"41:60",IIF(得分<81,"61:80","81:100"))))


Select CHOOSE((得分-1)/20+1,"1:20","21:40","41:60","61:80","81:100") AS 范围,
COUNT(得分) AS 个数
FROM [物理成绩$]
GROUP BY CHOOSE((得分-1)/20+1,"1:20","21:40","41:60","61:80","81:100")

Select PARTITION(得分,1,100,20) AS 范围,COUNT(得分) AS 个数
FROM [物理成绩$]
GROUP BY PARTITION(得分,1,100,20)

Select A.水果,A.水果号列,B.颜色号列,B.颜色
FROM [水果$] A,
     [颜色$] B
Where A.水果号列=B.颜色号列

Select A.定额名称,单位,数量,单价
FROM [材料进货表$] A,[单价表$] B
Where A.定额名称=B.定额名称

Select 部门编号,A.部门名称,部门负责人,员工编号,员工姓名,员工性别,员工学历,员工职称
FROM [部门编制$] A
LEFT OUTER JOIN 
[部门人员$] B
ON A.部门名称=B.部门名称
orDER BY 部门编号

Select A.城市,满意度,营业厅,修障服务
FROM ([满意度$] A
LEFT OUTER JOIN
[营业厅$] B
ON A.城市=B.城市)
LEFT OUTER JOIN
[修障服务$] C
ON A.城市=C.城市
orDER BY A.城市

Select A.*,B.姓名 AS 户主姓名 
FROM  [人口登记$] A
LEFT OUTER JOIN
(Select 姓名,户号
FROM [人口登记$]
Where 与户主关系="户主") B
ON A.户号=B.户号
orDER BY A.姓名

Select 业务员,销售数量
FROM [销售记录$]
Where 销售数量 >
(Select AVG(销售数量) AS 平均销售数量
FROM [销售记录$])
orDER BY 业务员

Select 品种,分公司,数量,金额
FROM [销售情况表$]
Where 数量>ALL(Select 数量
               FROM [销售情况表$] 
               Where 分公司='北京分公司'
               )
orDER BY 分公司

Select 教工号,姓名,课程号,所在系,性别,年龄
FROM [教工$] A
Where (Select AVG(年龄)
FROM [教工$] 
Where 所在系=A.所在系) >
(Select AVG(年龄) 
FROM [教工$] )
orDER BY 教工号

Select A.*,
(Select 1+COUNT(*)
FROM [销售数量$] B
Where B.城市=A.城市 AND B.销售数量 > A.销售数量) AS 销售数量排名
FROM [销售数量$] A

Select 省份,项目设计,SUM(数量) AS 数量,SUM(金额) AS 金额
FROM [项目表$]
GROUP BY 省份,项目设计
UNION 
Select A.省份 & ' 汇总',A.行数,B.数量,B.金额
FROM 
( Select 省份,COUNT(*) AS 行数
FROM
( Select DISTINCT 省份,项目设计
FROM [项目表$] )
GROUP BY 省份) A
INNER JOIN
( Select 省份,SUM(数量) AS 数量,SUM(金额) AS 金额
FROM [项目表$]
GROUP BY 省份 ) B
ON A.省份=B.省份
UNION ALL
Select DISTINCT " 总计","",
(Select SUM(数量) FROM [项目表$]),
(Select SUM(金额) FROM [项目表$])
FROM [项目表$]

Select "车间部" AS 总部门,*
FROM [D:\车间部.xlsx].[一车间$]
UNION ALL
Select "车间部" AS 总部门,*
FROM [D:\车间部.xlsx].[二车间$]
UNION ALL
Select "销售部" AS 总部门,*
FROM [D:\销售部.xlsx].[销售1部$]
UNION ALL
Select "销售部" AS 总部门,*
FROM [D:\销售部.xlsx].[销售2部$]
UNION ALL
Select "经理室" AS 总部门,*
FROM [D:\经理室.xlsx].[经理室$]
UNION ALL
Select "财务部" AS 总部门,*
FROM [D:\财务部.xlsx].[财务部$]
UNION ALL
Select "人力资源部" AS 总部门,*
FROM [D:\人力资源部.xlsx].[人力资源部$]
UNION ALL
Select "技改办" AS 总部门,*
FROM [D:\技改办.xlsx].[技改办$]

Access软件网官方交流QQ群 (群号:54525238)       Access源码网店

常见问答:

技术分类:

相关资源:

专栏作家

关于我们 | 服务条款 | 在线投稿 | 友情链接 | 网站统计 | 网站帮助