LibSQL+SQLServer: Implement first cut of SELECT ... ORDER BY foo

Ordering is done by replacing the straight Vector holding the query
result in the SQLResult object with a dedicated Vector subclass that
inserts result rows according to their sort key using a binary search.
This is done in the ResultSet class.

There are limitations:
- "SELECT ... ORDER BY 1" (or 2 or 3 etc) is supposed to sort by the
n-th result column. This doesn't work yet
- "SELECT ... column-expression alias ... ORDER BY alias" is supposed to
sort by the column with the given alias. This doesn't work yet

What does work however is something like
```SELECT foo FROM bar SORT BY quux```
i.e. sorted by a column not in the result set. Once functions are
supported it should be possible to sort by random functions.
This commit is contained in:
Jan de Visser 2022-01-12 09:49:43 -05:00 committed by Andreas Kling
parent 53cd87cc1d
commit 7fc901d1b3
Notes: sideshowbarker 2024-07-17 20:45:54 +09:00
7 changed files with 205 additions and 17 deletions

View file

@ -216,7 +216,7 @@ TEST_CASE(select_with_column_names)
EXPECT(result->error().code == SQL::SQLErrorCode::NoError);
EXPECT(result->has_results());
EXPECT_EQ(result->results().size(), 5u);
EXPECT_EQ(result->results()[0].size(), 1u);
EXPECT_EQ(result->results()[0].row.size(), 1u);
}
TEST_CASE(select_with_nonexisting_column_name)
@ -258,7 +258,7 @@ TEST_CASE(select_with_where)
EXPECT(result->has_results());
EXPECT_EQ(result->results().size(), 2u);
for (auto& row : result->results()) {
EXPECT(row[1].to_int().value() > 44);
EXPECT(row.row[1].to_int().value() > 44);
}
}
@ -291,11 +291,11 @@ TEST_CASE(select_cross_join)
EXPECT(result->has_results());
EXPECT_EQ(result->results().size(), 25u);
for (auto& row : result->results()) {
EXPECT(row.size() == 4);
EXPECT(row[1].to_int().value() >= 42);
EXPECT(row[1].to_int().value() <= 46);
EXPECT(row[3].to_int().value() >= 40);
EXPECT(row[3].to_int().value() <= 48);
EXPECT(row.row.size() == 4);
EXPECT(row.row[1].to_int().value() >= 42);
EXPECT(row.row[1].to_int().value() <= 46);
EXPECT(row.row[3].to_int().value() >= 40);
EXPECT(row.row[3].to_int().value() <= 48);
}
}
@ -331,10 +331,10 @@ TEST_CASE(select_inner_join)
EXPECT(result->has_results());
EXPECT_EQ(result->results().size(), 1u);
auto& row = result->results()[0];
EXPECT_EQ(row.size(), 3u);
EXPECT_EQ(row[0].to_int().value(), 42);
EXPECT_EQ(row[1].to_string(), "Test_1");
EXPECT_EQ(row[2].to_string(), "Test_12");
EXPECT_EQ(row.row.size(), 3u);
EXPECT_EQ(row.row[0].to_int().value(), 42);
EXPECT_EQ(row.row[1].to_string(), "Test_1");
EXPECT_EQ(row.row[2].to_string(), "Test_12");
}
TEST_CASE(select_with_like)
@ -410,4 +410,104 @@ TEST_CASE(select_with_like)
EXPECT(!result->has_results());
}
TEST_CASE(select_with_order)
{
ScopeGuard guard([]() { unlink(db_name); });
auto database = SQL::Database::construct(db_name);
EXPECT(!database->open().is_error());
create_table(database);
auto result = execute(database,
"INSERT INTO TestSchema.TestTable ( TextColumn, IntColumn ) VALUES "
"( 'Test_5', 44 ), "
"( 'Test_2', 42 ), "
"( 'Test_1', 47 ), "
"( 'Test_3', 40 ), "
"( 'Test_4', 41 );");
EXPECT(result->error().code == SQL::SQLErrorCode::NoError);
EXPECT(result->inserted() == 5);
result = execute(database, "SELECT TextColumn, IntColumn FROM TestSchema.TestTable ORDER BY IntColumn;");
EXPECT(result->error().code == SQL::SQLErrorCode::NoError);
EXPECT(result->has_results());
auto rows = result->results();
EXPECT_EQ(rows.size(), 5u);
EXPECT_EQ(rows[0].row[1].to_int().value(), 40);
EXPECT_EQ(rows[1].row[1].to_int().value(), 41);
EXPECT_EQ(rows[2].row[1].to_int().value(), 42);
EXPECT_EQ(rows[3].row[1].to_int().value(), 44);
EXPECT_EQ(rows[4].row[1].to_int().value(), 47);
result = execute(database, "SELECT TextColumn, IntColumn FROM TestSchema.TestTable ORDER BY TextColumn;");
EXPECT(result->error().code == SQL::SQLErrorCode::NoError);
EXPECT(result->has_results());
rows = result->results();
EXPECT_EQ(rows.size(), 5u);
EXPECT_EQ(rows[0].row[0].to_string(), "Test_1");
EXPECT_EQ(rows[1].row[0].to_string(), "Test_2");
EXPECT_EQ(rows[2].row[0].to_string(), "Test_3");
EXPECT_EQ(rows[3].row[0].to_string(), "Test_4");
EXPECT_EQ(rows[4].row[0].to_string(), "Test_5");
}
TEST_CASE(select_with_order_two_columns)
{
ScopeGuard guard([]() { unlink(db_name); });
auto database = SQL::Database::construct(db_name);
EXPECT(!database->open().is_error());
create_table(database);
auto result = execute(database,
"INSERT INTO TestSchema.TestTable ( TextColumn, IntColumn ) VALUES "
"( 'Test_5', 44 ), "
"( 'Test_2', 42 ), "
"( 'Test_1', 47 ), "
"( 'Test_2', 40 ), "
"( 'Test_4', 41 );");
EXPECT(result->error().code == SQL::SQLErrorCode::NoError);
EXPECT(result->inserted() == 5);
result = execute(database, "SELECT TextColumn, IntColumn FROM TestSchema.TestTable ORDER BY TextColumn, IntColumn;");
EXPECT(result->error().code == SQL::SQLErrorCode::NoError);
EXPECT(result->has_results());
auto rows = result->results();
EXPECT_EQ(rows.size(), 5u);
EXPECT_EQ(rows[0].row[0].to_string(), "Test_1");
EXPECT_EQ(rows[0].row[1].to_int().value(), 47);
EXPECT_EQ(rows[1].row[0].to_string(), "Test_2");
EXPECT_EQ(rows[1].row[1].to_int().value(), 40);
EXPECT_EQ(rows[2].row[0].to_string(), "Test_2");
EXPECT_EQ(rows[2].row[1].to_int().value(), 42);
EXPECT_EQ(rows[3].row[0].to_string(), "Test_4");
EXPECT_EQ(rows[3].row[1].to_int().value(), 41);
EXPECT_EQ(rows[4].row[0].to_string(), "Test_5");
EXPECT_EQ(rows[4].row[1].to_int().value(), 44);
}
TEST_CASE(select_with_order_by_column_not_in_result)
{
ScopeGuard guard([]() { unlink(db_name); });
auto database = SQL::Database::construct(db_name);
EXPECT(!database->open().is_error());
create_table(database);
auto result = execute(database,
"INSERT INTO TestSchema.TestTable ( TextColumn, IntColumn ) VALUES "
"( 'Test_5', 44 ), "
"( 'Test_2', 42 ), "
"( 'Test_1', 47 ), "
"( 'Test_3', 40 ), "
"( 'Test_4', 41 );");
EXPECT(result->error().code == SQL::SQLErrorCode::NoError);
EXPECT(result->inserted() == 5);
result = execute(database, "SELECT TextColumn FROM TestSchema.TestTable ORDER BY IntColumn;");
EXPECT(result->error().code == SQL::SQLErrorCode::NoError);
EXPECT(result->has_results());
auto rows = result->results();
EXPECT_EQ(rows.size(), 5u);
EXPECT_EQ(rows[0].row[0].to_string(), "Test_3");
EXPECT_EQ(rows[1].row[0].to_string(), "Test_4");
EXPECT_EQ(rows[2].row[0].to_string(), "Test_2");
EXPECT_EQ(rows[3].row[0].to_string(), "Test_5");
EXPECT_EQ(rows[4].row[0].to_string(), "Test_1");
}
}

View file

@ -7,6 +7,7 @@
#include <LibSQL/AST/AST.h>
#include <LibSQL/Database.h>
#include <LibSQL/Meta.h>
#include <LibSQL/ResultSet.h>
#include <LibSQL/Row.h>
namespace SQL::AST {
@ -77,6 +78,14 @@ RefPtr<SQLResult> Select::execute(ExecutionContext& context) const
}
}
bool has_ordering { false };
AK::NonnullRefPtr<TupleDescriptor> sort_descriptor = AK::adopt_ref(*new TupleDescriptor);
for (auto& term : m_ordering_term_list) {
sort_descriptor->append(TupleElementDescriptor { .order = term.order() });
has_ordering = true;
}
Tuple sort_key(sort_descriptor);
for (auto& row : rows) {
context.current_row = &row;
if (where_clause()) {
@ -93,7 +102,17 @@ RefPtr<SQLResult> Select::execute(ExecutionContext& context) const
return context.result;
tuple.append(value);
}
context.result->append(tuple);
if (has_ordering) {
sort_key.clear();
for (auto& term : m_ordering_term_list) {
auto value = term.expression()->evaluate(context);
if (context.result->has_error())
return context.result;
sort_key.append(value);
}
}
context.result->insert(tuple, sort_key);
}
return context.result;
}

View file

@ -17,6 +17,7 @@ set(SOURCES
Index.cpp
Key.cpp
Meta.cpp
ResultSet.cpp
Row.cpp
Serializer.cpp
SQLClient.cpp

View file

@ -0,0 +1,38 @@
/*
* Copyright (c) 2022, Jan de Visser <jan@de-visser.net>
*
* SPDX-License-Identifier: BSD-2-Clause
*/
#include <LibSQL/ResultSet.h>
namespace SQL {
size_t ResultSet::binary_search(Tuple const& sort_key, size_t low, size_t high)
{
if (high <= low) {
auto compare = sort_key.compare(at(low).sort_key);
return (compare > 0) ? low + 1 : low;
}
auto mid = (low + high) / 2;
auto compare = sort_key.compare(at(mid).sort_key);
if (compare == 0)
return mid + 1;
if (compare > 0)
return binary_search(sort_key, mid + 1, high);
return binary_search(sort_key, low, mid);
}
void ResultSet::insert_row(Tuple const& row, Tuple const& sort_key)
{
if ((sort_key.size() == 0) || is_empty()) {
empend(row, sort_key);
return;
}
auto ix = binary_search(sort_key, 0, size() - 1);
insert(ix, ResultRow { row, sort_key });
}
}

View file

@ -0,0 +1,29 @@
/*
* Copyright (c) 2022, Jan de Visser <jan@de-visser.net>
*
* SPDX-License-Identifier: BSD-2-Clause
*/
#pragma once
#include <AK/Vector.h>
#include <LibSQL/Tuple.h>
#include <LibSQL/Type.h>
namespace SQL {
struct ResultRow {
Tuple row;
Tuple sort_key;
};
class ResultSet : public Vector<ResultRow> {
public:
ResultSet() = default;
void insert_row(Tuple const& row, Tuple const& sort_key);
private:
size_t binary_search(Tuple const& sort_key, size_t low, size_t high);
};
}

View file

@ -10,6 +10,7 @@
#include <AK/NonnullOwnPtrVector.h>
#include <AK/Vector.h>
#include <LibCore/Object.h>
#include <LibSQL/ResultSet.h>
#include <LibSQL/Tuple.h>
#include <LibSQL/Type.h>
@ -110,10 +111,10 @@ class SQLResult : public Core::Object {
C_OBJECT(SQLResult)
public:
void append(Tuple const& tuple)
void insert(Tuple const& row, Tuple const& sort_key)
{
m_has_results = true;
m_result_set.append(tuple);
m_result_set.insert_row(row, sort_key);
}
SQLCommand command() const { return m_command; }
@ -129,7 +130,7 @@ public:
bool has_error() const { return m_error.code != SQLErrorCode::NoError; }
SQLError const& error() const { return m_error; }
bool has_results() const { return m_has_results; }
Vector<Tuple> const& results() const { return m_result_set; }
ResultSet const& results() const { return m_result_set; }
private:
SQLResult() = default;
@ -161,7 +162,7 @@ private:
int m_insert_count { 0 };
int m_delete_count { 0 };
bool m_has_results { false };
Vector<Tuple> m_result_set;
ResultSet m_result_set;
};
}

View file

@ -104,7 +104,7 @@ void SQLStatement::next()
return;
}
if (m_index < m_result->results().size()) {
auto& tuple = m_result->results()[m_index++];
auto& tuple = m_result->results()[m_index++].row;
client_connection->async_next_result(statement_id(), tuple.to_string_vector());
deferred_invoke([this]() {
next();