提交 f4e9acde authored 作者: Thomas Mueller's avatar Thomas Mueller

Recursive queries.

上级 f6d3b6c1
......@@ -22,6 +22,8 @@ Advanced
Large Objects</a><br />
<a href="#linked_tables">
Linked Tables</a><br />
<a href="#recursive_queries">
Recursive Queries</a><br />
<a href="#transaction_isolation">
Transaction Isolation</a><br />
<a href="#mvcc">
......@@ -1188,6 +1190,66 @@ one's annual risk of being hit by a meteorite is estimated to be one chance in 1
that means the probability is about 0.000'000'000'06.
</p>
<h2 id="recursive_queries">Recursive Queries</h2>
<p>
H2 has experimental support for recursive queries, using so called "common table expressions".
Examples:
</p>
<pre>
WITH RECURSIVE T(N) AS (
SELECT 1
UNION ALL
SELECT N+1 FROM T WHERE N&lt;10
)
SELECT * FROM T;
-- returns the values 1 .. 10
WITH RECURSIVE T(N) AS (
SELECT 1
UNION ALL
SELECT N*2 FROM T WHERE N&lt;10
)
SELECT * FROM T;
-- returns the values 1, 2, 4, 8, 16
CREATE TABLE FOLDER(ID INT PRIMARY KEY, NAME VARCHAR(255), PARENT INT);
INSERT INTO FOLDER VALUES(1, null, null), (2, 'src', 1),
(3, 'main', 2), (4, 'org', 3), (5, 'test', 2);
WITH LINK(ID, NAME, LEVEL) AS (
SELECT ID, NAME, 0 FROM FOLDER WHERE PARENT IS NULL
UNION ALL
SELECT FOLDER.ID, IFNULL(LINK.NAME || '/', '') || FOLDER.NAME, LEVEL + 1
FROM LINK INNER JOIN FOLDER ON LINK.ID = FOLDER.PARENT
)
SELECT NAME FROM LINK WHERE NAME IS NOT NULL ORDER BY ID;
-- src
-- src/main
-- src/main/org
-- src/test
</pre>
<p>
Limitations: Recursive queries need to be of the type <code>UNION ALL</code>,
and the recursion needs to be on the second part of the query.
No tables or views with the name of the table expression may exist.
Different table expression names need to be used when using multiple distinct table
expressions within the same transaction and for the same session.
All columns of the table expression are of type <code>VARCHAR</code>.
Parameters are only supported within the last <code>SELECT</code> statement
(a workaround is to use session variables like <code>@start</code>
within the table expression).
The syntax is:
</p>
<pre>
WITH RECURSIVE recursiveQueryName(columnName, ...) AS (
nonRecursiveSelect
UNION ALL
recursiveSelect
)
select
</pre>
<h2 id="system_properties">Settings Read from System Properties</h2>
<p>
Some settings of the database can be set on the command line using
......
......@@ -1391,6 +1391,8 @@ public class Parser {
command.setCommand(parseInsert());
} else if (readIf("MERGE")) {
command.setCommand(parseMerge());
} else if (readIf("WITH")) {
command.setCommand(parserWith());
} else {
throw getSyntaxError();
}
......@@ -3968,6 +3970,7 @@ public class Parser {
}
private Query parserWith() {
readIf("RECURSIVE");
String tempViewName = readIdentifierWithSchema();
Schema schema = getSchema();
Table recursiveTable;
......@@ -3977,8 +3980,20 @@ public class Parser {
for (String c : cols) {
columns.add(new Column(c, Value.STRING));
}
Table old = session.findLocalTempTable(tempViewName);
if (old != null) {
if (!(old instanceof TableView)) {
throw DbException.get(ErrorCode.TABLE_OR_VIEW_ALREADY_EXISTS_1, tempViewName);
}
TableView tv = (TableView) old;
if (!tv.isTableExpression()) {
throw DbException.get(ErrorCode.TABLE_OR_VIEW_ALREADY_EXISTS_1, tempViewName);
}
session.removeLocalTempTable(old);
}
CreateTableData data = new CreateTableData();
data.id = database.allocateObjectId();
data.columns = columns;
data.tableName = tempViewName;
data.temporary = true;
data.persistData = true;
......@@ -3987,21 +4002,26 @@ public class Parser {
data.session = session;
recursiveTable = schema.createTable(data);
session.addLocalTempTable(recursiveTable);
String querySQL = StringUtils.fromCacheOrNew(sqlCommand.substring(parseIndex));
read("AS");
Query withQuery = parseSelect();
withQuery.prepare();
session.removeLocalTempTable(recursiveTable);
String querySQL;
try {
read("AS");
read("(");
Query withQuery = parseSelect();
read(")");
withQuery.prepare();
querySQL = StringUtils.fromCacheOrNew(withQuery.getPlanSQL());
} finally {
session.removeLocalTempTable(recursiveTable);
}
int id = database.allocateObjectId();
TableView view = new TableView(schema, id, tempViewName, querySQL, null, cols, session, true);
view.setTableExpression(true);
view.setTemporary(true);
// view.setOnCommitDrop(true);
session.addLocalTempTable(view);
Query query = parseSelect();
query.prepare();
query.setPrepareAlways(true);
// session.removeLocalTempTable(view);
return query;
view.setOnCommitDrop(true);
Query q = parseSelect();
q.setPrepareAlways(true);
return q;
}
private CreateView parseCreateView(boolean force, boolean orReplace) {
......
......@@ -73,10 +73,22 @@ public class SelectUnion extends Query {
this.unionType = type;
}
public int getUnionType() {
return unionType;
}
public void setRight(Query select) {
right = select;
}
public Query getLeft() {
return left;
}
public Query getRight() {
return right;
}
public void setSQL(String sql) {
this.sqlStatement = sql;
}
......@@ -100,6 +112,11 @@ public class SelectUnion extends Query {
return result;
}
public LocalResult getEmptyResult() {
int columnCount = left.getColumnCount();
return new LocalResult(session, expressionArray, columnCount);
}
protected LocalResult queryWithoutCache(int maxrows) {
if (maxrows != 0) {
if (limitExpr != null) {
......
......@@ -8,11 +8,14 @@ package org.h2.index;
import java.util.ArrayList;
import org.h2.command.dml.Query;
import org.h2.command.dml.SelectUnion;
import org.h2.constant.ErrorCode;
import org.h2.engine.Constants;
import org.h2.engine.Session;
import org.h2.expression.Comparison;
import org.h2.expression.Parameter;
import org.h2.message.DbException;
import org.h2.result.LocalResult;
import org.h2.result.ResultInterface;
import org.h2.result.Row;
import org.h2.result.SearchRow;
......@@ -57,8 +60,10 @@ public class ViewIndex extends BaseIndex {
this.indexMasks = masks;
this.createSession = session;
columns = new Column[0];
query = getQuery(session, masks);
planSQL = query.getPlanSQL();
if (!recursive) {
query = getQuery(session, masks);
planSQL = query.getPlanSQL();
}
}
public Session getSession() {
......@@ -98,6 +103,9 @@ public class ViewIndex extends BaseIndex {
}
public double getCost(Session session, int[] masks) {
if (recursive) {
return 1000;
}
IntArray masksArray = new IntArray(masks == null ? Utils.EMPTY_INT_ARRAY : masks);
CostElement cachedCost = costCache.get(masksArray);
if (cachedCost != null) {
......@@ -135,9 +143,6 @@ public class ViewIndex extends BaseIndex {
}
}
}
if (recursive) {
return 10;
}
String sql = q.getPlanSQL();
q = (Query) session.prepare(sql, true);
}
......@@ -150,6 +155,45 @@ public class ViewIndex extends BaseIndex {
}
public Cursor find(Session session, SearchRow first, SearchRow last) {
if (recursive) {
if (view.getRecursiveResult() != null) {
ResultInterface r = view.getRecursiveResult();
r.reset();
return new ViewCursor(table, r);
}
if (query == null) {
query = (Query) createSession.prepare(querySQL, true);
planSQL = query.getPlanSQL();
}
if (!(query instanceof SelectUnion)) {
throw DbException.get(ErrorCode.SYNTAX_ERROR_2, "recursive queries without UNION ALL");
}
SelectUnion union = (SelectUnion) query;
if (union.getUnionType() != SelectUnion.UNION_ALL) {
throw DbException.get(ErrorCode.SYNTAX_ERROR_2, "recursive queries without UNION ALL");
}
Query left = union.getLeft();
ResultInterface r = left.query(0);
LocalResult result = union.getEmptyResult();
while (r.next()) {
result.addRow(r.currentRow());
}
Query right = union.getRight();
r.reset();
view.setRecursiveResult(r);
while (true) {
r = right.query(0);
if (r.getRowCount() == 0) {
break;
}
while (r.next()) {
result.addRow(r.currentRow());
}
r.reset();
view.setRecursiveResult(r);
}
return new ViewCursor(table, result);
}
ArrayList<Parameter> paramList = query.getParameters();
for (int i = 0; originalParameters != null && i < originalParameters.size(); i++) {
Parameter orig = originalParameters.get(i);
......@@ -282,4 +326,8 @@ public class ViewIndex extends BaseIndex {
return 0;
}
public boolean isRecursive() {
return recursive;
}
}
......@@ -20,6 +20,7 @@ import org.h2.index.Index;
import org.h2.index.IndexType;
import org.h2.index.ViewIndex;
import org.h2.message.DbException;
import org.h2.result.ResultInterface;
import org.h2.result.Row;
import org.h2.schema.Schema;
import org.h2.util.IntArray;
......@@ -49,6 +50,8 @@ public class TableView extends Table {
private long maxDataModificationId;
private User owner;
private Query topQuery;
private ResultInterface recursiveResult;
private boolean tableExpression;
public TableView(Schema schema, int id, String name, String querySQL, ArrayList<Parameter> params, String[] columnNames,
Session session, boolean recursive) {
......@@ -118,10 +121,8 @@ public class TableView extends Table {
cols[i] = new Column(columnNames[i], Value.STRING);
}
index.setRecursive(true);
recursive = true;
createException = null;
}
}
setColumns(cols);
if (getId() != 0) {
......@@ -385,7 +386,26 @@ public class TableView extends Table {
}
public boolean isDeterministic() {
if (recursive) {
return false;
}
return viewQuery.isEverything(ExpressionVisitor.DETERMINISTIC);
}
public void setRecursiveResult(ResultInterface recursiveResult) {
this.recursiveResult = recursiveResult;
}
public ResultInterface getRecursiveResult() {
return recursiveResult;
}
public void setTableExpression(boolean tableExpression) {
this.tableExpression = tableExpression;
}
public boolean isTableExpression() {
return tableExpression;
}
}
......@@ -46,6 +46,7 @@ import org.h2.test.db.TestOutOfMemory;
import org.h2.test.db.TestPowerOff;
import org.h2.test.db.TestQueryCache;
import org.h2.test.db.TestReadOnly;
import org.h2.test.db.TestRecursiveQueries;
import org.h2.test.db.TestRights;
import org.h2.test.db.TestRunscript;
import org.h2.test.db.TestSQLInjection;
......@@ -534,6 +535,7 @@ kill -9 `jps -l | grep "org.h2.test." | cut -d " " -f 1`
new TestPowerOff().runTest(this);
new TestQueryCache().runTest(this);
new TestReadOnly().runTest(this);
new TestRecursiveQueries().runTest(this);
new TestRights().runTest(this);
new TestRunscript().runTest(this);
new TestSQLInjection().runTest(this);
......
/*
* Copyright 2004-2010 H2 Group. Multiple-Licensed under the H2 License,
* Version 1.0, and under the Eclipse Public License, Version 1.0
* (http://h2database.com/html/license.html).
* Initial Developer: H2 Group
*/
package org.h2.test.db;
import java.sql.Connection;
import java.sql.PreparedStatement;
import java.sql.ResultSet;
import java.sql.Statement;
import org.h2.test.TestBase;
/**
* Test recursive queries using WITH.
*/
public class TestRecursiveQueries extends TestBase {
/**
* Run just this test.
*
* @param a ignored
*/
public static void main(String... a) throws Exception {
TestBase.createCaller().init().test();
}
public void test() throws Exception {
deleteDb("recursiveQueries");
Connection conn = getConnection("recursiveQueries");
Statement stat = conn.createStatement();
PreparedStatement prep, prep2;
ResultSet rs;
stat = conn.createStatement();
rs = stat.executeQuery("with recursive t(n) as (select 1 union all select n+1 from t where n<3) select * from t");
assertTrue(rs.next());
assertEquals(1, rs.getInt(1));
assertTrue(rs.next());
assertEquals(2, rs.getInt(1));
assertTrue(rs.next());
assertEquals(3, rs.getInt(1));
assertFalse(rs.next());
prep = conn.prepareStatement("with recursive t(n) as (select 1 union all select n+1 from t where n<3) select * from t where n>?");
prep.setInt(1, 2);
rs = prep.executeQuery();
assertTrue(rs.next());
assertEquals(3, rs.getInt(1));
assertFalse(rs.next());
prep.setInt(1, 1);
rs = prep.executeQuery();
assertTrue(rs.next());
assertEquals(2, rs.getInt(1));
assertTrue(rs.next());
assertEquals(3, rs.getInt(1));
assertFalse(rs.next());
prep = conn.prepareStatement("with recursive t(n) as (select @start union all select n+@inc from t where n<@end) select * from t");
prep2 = conn.prepareStatement("select @start:=?, @inc:=?, @end:=?");
prep2.setInt(1, 10);
prep2.setInt(2, 2);
prep2.setInt(3, 14);
prep2.execute();
rs = prep.executeQuery();
assertTrue(rs.next());
assertEquals(10, rs.getInt(1));
assertTrue(rs.next());
assertEquals(12, rs.getInt(1));
assertTrue(rs.next());
assertEquals(14, rs.getInt(1));
assertFalse(rs.next());
prep2.setInt(1, 100);
prep2.setInt(2, 3);
prep2.setInt(3, 103);
prep2.execute();
rs = prep.executeQuery();
assertTrue(rs.next());
assertEquals(100, rs.getInt(1));
assertTrue(rs.next());
assertEquals(103, rs.getInt(1));
assertFalse(rs.next());
conn.close();
deleteDb("recursiveQueries");
}
}
--- special grammar and test cases ---------------------------------------------------------------------------------------------
create table folder(id int primary key, name varchar(255), parent int);
> ok
insert into folder values(1, null, null), (2, 'bin', 1), (3, 'docs', 1), (4, 'html', 3), (5, 'javadoc', 3), (6, 'ext', 1), (7, 'service', 1), (8, 'src', 1), (9, 'docsrc', 8), (10, 'installer', 8), (11, 'main', 8), (12, 'META-INF', 11), (13, 'org', 11), (14, 'h2', 13), (15, 'test', 8), (16, 'tools', 8);
> update count: 16
with link(id, name, level) as (select id, name, 0 from folder where parent is null union all select folder.id, ifnull(link.name || '/', '') || folder.name, level + 1 from link inner join folder on link.id = folder.parent) select name from link where name is not null order by id;
> NAME
> -----------------
> bin
> docs
> docs/html
> docs/javadoc
> ext
> service
> src
> src/docsrc
> src/installer
> src/main
> src/main/META-INF
> src/main/org
> src/main/org/h2
> src/test
> src/tools
> rows (ordered): 15
drop table folder;
> ok
create table test(id int);
> ok
......
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论