|
本帖最后由 wcymiss 于 2012-2-5 20:11 编辑
神奇的吴版,神奇的转置九式{:soso_e179:}{:soso_e179:}
以下sql语句均需把连接文本里的"HDR=YES"改为"HDR=NO",并去掉”数据区域属性“中的”包含字段名“的勾。
不大清楚书写规范,语句的断行都是自己想当然的:
转置1:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT f1 AS 结果,f1&f2 AS 字段 FROM [数据$] UNION
- SELECT f2,f1&f2&f1 FROM [数据$])
- GROUP BY 1 PIVOT 字段
复制代码
转置2:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT 结果,INT((COUNT(辅助2)-1)/6) AS 列字段,(COUNT(辅助2)-1) MOD 6 AS 行字段 FROM
- (SELECT f1 AS 结果,f1&f2 AS 辅助1 FROM [数据$] UNION
- SELECT f2,f1&f2&f1 FROM [数据$])a,
- (SELECT f1&f2 AS 辅助2 FROM [数据$] UNION
- SELECT f1&f2&f1 FROM [数据$])b
- WHERE 辅助1>=辅助2 GROUP BY 结果,辅助1)
- GROUP BY 列字段 PIVOT 行字段
复制代码 昨天(2月4日)正好与人讨论域聚合函数的用法,想起dcount、dsum都可以求得序号,而且字符少些(效率好像无提高):
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT 结果,INT(序号/6) AS 列字段,序号 MOD 6 AS 行字段 FROM
- (SELECT F1 AS 结果,DSUM(1,"数据$","F1&F2<='"&F1&F2&"'")*2-2 AS 序号 FROM [数据$] UNION
- SELECT F2,DSUM(1,"数据$","F1&F2<='"&F1&F2&"'")*2-1 FROM [数据$])
- )
- GROUP BY 列字段 PIVOT 行字段
复制代码
转置3:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT 结果,列字段1,COUNT(辅助2) AS 行字段 FROM
- (SELECT f1 AS 结果,f1&f2 AS 辅助1,f1 AS 列字段1 FROM [数据$] UNION
- SELECT f2,f1&f2&f1,f1 FROM [数据$])a,
- (SELECT f1&f2 AS 辅助2,f1 AS 列字段2 FROM [数据$] UNION
- SELECT f1&f2&f1,f1 FROM [数据$])b
- WHERE 辅助1>=辅助2 AND 列字段1=列字段2 GROUP BY 结果,列字段1,辅助1)
- GROUP BY 列字段1 PIVOT 行字段
复制代码 也用域聚合函数:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT F1 AS 结果,F1 AS 列字段,
- DSUM(1,"数据$","F1&F2<='"&F1&F2&"'AND F1='"&F1&"'")*2 AS 序号
- FROM [数据$] UNION
- SELECT F2,F1,
- DSUM(1,"数据$","F1&F2<='"&F1&F2&"'AND F1='"&F1&"'")*2+1
- FROM [数据$])
- GROUP BY 列字段 PIVOT 序号
复制代码 本不想*2,想用dsum()+0.5,结果确发现pivot后,”1.5“变成了”1_5“排在了所有整数的后面。。。
转置4:
- TRANSFORM FIRST(结果) SELECT 列字段 FROM
- (SELECT a.f1 AS 列字段,a.f2 AS 结果,COUNT(b.f1) AS 行字段 FROM [数据$]a,[数据$]b
- WHERE a.f1=b.f1 AND a.f2>=b.f2 GROUP BY a.f1,a.f2)
- GROUP BY 列字段 PIVOT 行字段
复制代码 域聚合函数:
- TRANSFORM FIRST(结果) SELECT 列字段 FROM
- (SELECT F2 AS 结果,F1 AS 列字段,
- DSUM(1,"数据$","F2<='"&F2&"'AND F1='"&F1&"'") AS 序号
- FROM [数据$])
- GROUP BY 列字段 PIVOT 序号
复制代码
转置5:
- TRANSFORM FIRST(结果) SELECT 列字段2 FROM
- (SELECT 列字段1,结果,列字段1 AS 列字段2,行字段 FROM
- (SELECT a.f1 AS 列字段1,a.f2 AS 结果,COUNT(b.f1) AS 行字段 FROM [数据$]a,[数据$]b
- WHERE a.f1=b.f1 AND a.f2>=b.f2 GROUP BY a.f1,a.f2) UNION
- SELECT f1&f1,NULL,NULL,1 FROM [数据$])
- GROUP BY 列字段1,列字段2 PIVOT 行字段
复制代码 或:
- TRANSFORM FIRST(结果) SELECT 列字段2 FROM
- (SELECT F2 AS 结果,F1 AS 列字段1,F1 AS 列字段2,
- DSUM(1,"数据$","F2<='"&F2&"'AND F1='"&F1&"'") AS 序号
- FROM [数据$] UNION
- SELECT NULL,f1&f1,NULL,1 FROM [数据$])
- GROUP BY 列字段1,列字段2 PIVOT 序号
复制代码
转置6:
- TRANSFORM FIRST(结果) SELECT 列字段2 FROM
- (SELECT 列字段1,结果,列字段1 AS 列字段2,行字段 FROM
- (SELECT a.f1 AS 列字段1,a.f2 AS 结果,COUNT(b.f1) AS 行字段 FROM [数据$]a,[数据$]b
- WHERE a.f1=b.f1 AND a.f2>=b.f2 GROUP BY a.f1,a.f2) UNION
- SELECT f1&f1,NULL,"总共("&COUNT(f2)&"人)",1 FROM [数据$]
- GROUP BY f1)
- GROUP BY 列字段1,列字段2 PIVOT 行字段
复制代码 或:
- TRANSFORM FIRST(结果) SELECT 列字段2 FROM
- (SELECT F2 AS 结果,F1 AS 列字段1,F1 AS 列字段2,
- DSUM(1,"数据$","F2<='"&F2&"'AND F1='"&F1&"'") AS 序号
- FROM [数据$] UNION
- SELECT NULL,f1&f1,"总共("&COUNT(f2)&"人)",1 FROM [数据$]
- GROUP BY f1)
- GROUP BY 列字段1,列字段2 PIVOT 序号
复制代码
转置7:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT a.f1 AS 列字段1,a.f2 AS 结果,
- (COUNT(b.f1)-1) MOD 3 +2 AS 行字段,INT((COUNT(b.f1)+2)/3) AS 列字段2
- FROM [数据$]a,[数据$]b
- WHERE a.f1&a.f2>=b.f1&b.f2 AND a.f1=b.f1 GROUP BY a.f1,a.f2 UNION
- SELECT f1,f1,1,1 FROM [数据$])
- GROUP BY 列字段1,列字段2 PIVOT 行字段
复制代码 或:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT 列字段1,INT(序号/3) AS 列字段2,结果,序号 MOD 3 +1 AS 行字段 FROM
- (SELECT F1 AS 列字段1,F2 AS 结果,
- DSUM(1,"数据$","F2<='"&F2&"'AND F1='"&F1&"'")-1 AS 序号 FROM [数据$])
- UNION SELECT F1,0,F1,0 FROM [数据$])
- GROUP BY 列字段1,列字段2 PIVOT 行字段
复制代码
转置8:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT a.f1 AS 列字段1,a.f2 AS 结果,(COUNT(b.f1)-1) MOD 3 +2 AS 行字段,
- INT((COUNT(b.f1)-1)/3) AS 列字段2 FROM [数据$]a,[数据$]b
- WHERE a.f1&a.f2>=b.f1&b.f2 and a.f1=b.f1 GROUP BY a.f1,a.f2 UNION
- SELECT a.f1,a.f1,1,INT((COUNT(b.f1)-1)/3) FROM [数据$]a,[数据$]b
- WHERE a.f1&a.f2>=b.f1&b.f2 AND a.f1=b.f1 GROUP BY a.f1,a.f2)
- GROUP BY 列字段1,列字段2 PIVOT 行字段
复制代码 或:
- TRANSFORM FIRST(结果) SELECT 列字段1 FROM
- (SELECT 列字段1,结果,INT(序号/3) AS 列字段2,序号 MOD 3 AS 行字段 FROM
- (SELECT F1 AS 列字段1,F2 AS 结果,
- DSUM(1,"数据$","F2<='"&F2&"'AND F1='"&F1&"'")-1 AS 序号 FROM [数据$])
- )
- GROUP BY 列字段1,列字段2 PIVOT 行字段
复制代码
转置9:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT a.f1 AS 列字段1,a.f2 AS 结果,
- (COUNT(b.f1)-1) MOD 3 +2 AS 行字段,INT((COUNT(b.f1)+2)/3) AS 列字段2
- FROM [数据$]a,[数据$]b
- WHERE a.f1&a.f2>=b.f1&b.f2 AND a.f1=b.f1 GROUP BY a.f1,a.f2 UNION
- SELECT f1,f1,1,1 FROM [数据$] UNION
- SELECT f1,'总共('&COUNT(f1)&'人)',1,2 FROM [数据$] GROUP BY f1)
- GROUP BY 列字段1,列字段2 PIVOT 行字段
复制代码 或:
- TRANSFORM FIRST(结果) SELECT NULL FROM
- (SELECT 列字段1,INT(序号/3) AS 列字段2,结果,序号 MOD 3 +1 AS 行字段 FROM
- (SELECT F1 AS 列字段1,F2 AS 结果,
- DSUM(1,"数据$","F2<='"&F2&"'AND F1='"&F1&"'")-1 AS 序号 FROM [数据$])
- UNION SELECT F1,0,F1,0 FROM [数据$] UNION
- SELECT F1,1,'总共('&COUNT(F1)&'人)',0 FROM [数据$]
- GROUP BY F1)
- GROUP BY 列字段1,列字段2 PIVOT 行字段
复制代码
|
评分
-
2
查看全部评分
-
|