Giter Club home page Giter Club logo

swift-kuery's Introduction

Kitura

APIDoc Build Status - Master macOS Linux Apache 2 Slack Status

Swift-Kuery

Swift-Kuery is a pluggable SQL database driver/SDK abstraction layer. Its main idea is to unify the APIs to the various relational databases, providing a Swifty yet SQL-like API. This allows easy switching between databases and forms the basis for an Object-Relational Mapping (ORM) framework.

Swift-Kuery-ORM is an ORM, built on top of Swift-Kuery, which allows you to simplify the persistence of model objects with your server.

Swift-Kuery is an easy to learn, consumable framework that comes with a set of implemented plugins.

Table of Contents

Swift version

The latest version of Swift-Kuery requires Swift 4.0 or newer. You can download this version of the Swift binaries by following this link. Compatibility with other Swift versions is not guaranteed.

Usage

This example demonstrates how to execute an SQL query using Swift-Kuery with the Swift-Kuery-PostgreSQL plugin.

The starting point for this example is an existing Swift package. If you don't have one already, create and enter a directory named e.g. SwiftKueryExample. Now run the swift package's init command, to create an executable type, by running swift package init --type executable.

Creating A PostgreSQL Database

  1. Install PostgreSQL

Mac

brew install postgresql

Ubuntu Linux

sudo apt-get install postgresql postgresql-contrib

  1. Create a school database

    createdb school
    psql school
    
  2. Create a grades table

    CREATE TABLE "Grades" (
        id varchar(100) PRIMARY KEY,
        course text NOT NULL,
        grade integer
    );  
    

Update your Package.swift file

Add Swift-Kuery and your Kuery plugin, in this case Swift-Kuery-PostgreSQL, to the dependencies within your application's Package.swift file. Substitute "x.x.x" with the latest Swift-Kuery release and "y.y.y" with the latest plugin release.

dependencies: [
    ...
    // Add this line
    .package(url: "https://github.com/Kitura/Swift-Kuery.git", from: "x.x.x"),
    .package(url: "https://github.com/Kitura/Swift-Kuery-PostgreSQL.git", from: "y.y.y"),
  ],
  targets: [
    .target(
      name: ...
      // Add the module to your target(s)
      dependencies: [..., "SwiftKuery", "SwiftKueryPostgreSQL"]),
  ]

Executing SQL queries

Inside the main.swift file:

  1. Add SwiftKuery and SwiftKueryPostgreSQL to your import statements:
import SwiftKuery
import SwiftKueryPostgreSQL
  1. Create a Table class, which matches the grades table you created in the database:
class Grades: Table {
    let tableName = "Grades"
    let id = Column("id", Int32.self, primaryKey: true)
    let course = Column("course", String.self)
    let grade = Column("grade", Int32.self)
}
let grades = Grades()
  1. Create a pool of connections to PostgreSQL:
let pool = PostgreSQLConnection.createPool(host: "localhost", port: 5432, options: [.databaseName("school")], poolOptions: ConnectionPoolOptions(initialCapacity: 10, maxCapacity: 50))
  1. Create some example students:
let students: [[Any]] = [[0, "computing", 92], [1, "physics", 75], [2, "history", 83]]
  1. Connect to database and perform an SQL query:
pool.getConnection() { connection, error in
    guard let connection = connection else {
        guard let error = error else {
            return print("Unknown error")
        }
        return print("Error when getting connection from pool: \(error.localizedDescription)")
    }
    let insertQuery = Insert(into: grades, rows: students)
    connection.execute(query: insertQuery) { insertResult in
        connection.execute(query: Select(from: grades)) { selectResult in
            guard let resultSet = selectResult.asResultSet else {
                return print("No result set returned from query")
            }
            resultSet.forEach() { row, error in
                guard let row = row else {
                    guard let error = error else {
                        // Processed all results
                        return
                    }
                    // Handle error
                    return
                }
                guard row.count == 3 else {
                    // Expecting three elements per row
                    return print("Row has wrong number of elements. Expecting 3, returned: \(row.count)")
                }
                print("Student \(row[0] ?? ""), studying \(row[1] ?? ""), scored \(row[2] ?? "")")
            }
        }
    }
}
  1. If you were to run the application at this point it would execute immediately because the SwiftKuery API behaves asynchronously. In the case of this simple executable you can add a Dispatch Semaphore to force the application to wait for the asynchronous callbacks to complete:
// Add the following after the existing imports:
import Dispatch
let waitSemaphore = DispatchSemaphore(value: 0)

// Update the forEach callback to look like:
resultSet.forEach() { row, error in
    guard let row = row else {
        // Processed all results
        waitSemaphore.signal()
        return
    }
    print("Student \(row[0] ?? ""), studying \(row[1] ?? ""), scored \(row[2] ?? "")")
}

// Add the following line at the end of the main.swift file
waitSemaphore.wait()
  1. Save the main.swift file. Run swift build to build the executable.
  2. Run the executable .build/debug/<yourPackageName>.

This will print the id, course and grade for each student, which are queried from the database:

Student 0, studying computing, scored 92
Student 1, studying physics, scored 75
Student 2, studying history, scored 83

If you go to your database with psql school and enter TABLE grades; you can see that the table has been populated with the student data.

SQL Injection Prevention using Parameterization

Unsanitized data that is used in dynamic queries is one of the most common causes of SQL injection vulnerabilities. Parameterizing queries can help to prevent SQL injection attacks.

The following code is vulnerable to SQL injection if supplied_key1 or supplied_key2 contain untrusted data (that is, data which has not been validated):

let query = Select(from: confidential)
  .where(confidential.key1 == supplied_key1 || confidential.key2 == supplied_key2)

connection.execute(query: query) { queryResult in
  ...
}

To guard against SQL Injection attacks, use the following parameterized version of the code:

let query = Select(from: confidential)
  .where(confidential.key1 == Parameter() || confidential.key2 == Parameter())

connection.execute(query: query, parameters: supplied_key1, supplied_key2) { queryResult in
  ...
}

Prepared Statements

If your application executes the same (or similar) SQL statements repeatedly with different parameters you may improve the performance of the application by using a prepared statement. Prepared statements can reduce parsing time as the database parses and compiles the statement template only once and then stores the result but doesn’t execute it. Later, the application supplies values for the parameters of the statement template and the database executes the statement.

For example, suppose our application needs to retrieve the average grade for courses with an average above a given value; a value which we want to vary. Let’s change our query to use a parameter instead of a predefined value:

let query = Select(grades.course, round(avg(grades.grade), to: 1).as("average"), from: grades)
            .group(by: grades.course)
            .having(avg(grades.grade) > Parameter())
            .order(by: .ASC(avg(grades.grade)))

Now, prepare the statement and execute as many times as required with different parameter values. Use the release function to free the prepared statement:

connection.prepareStatement(query) { result in
    guard let statement = result.asPreparedStatement else {
        // Handle error
        return
    }
    // Execute the statement
    connection.execute(preparedStatement: preparedStatement, parameters: [70]) { result in
        ...
        connection.execute(preparedStatement: preparedStatement, parameters: [25]) { result in
            ...
            connection.release(preparedStatement: preparedStatement) { result in
                ...
            }
        }
    }
}

Note: preparedStatement is a plugin-specific handle for the prepared statement.

Schema Management

Table creation

Swift-Kuery enables you to create tables on the database server.

Let's revisit the Grades table, which we used in our Example above:

class Grades: Table {
    let tableName = "Grades"
    let id = Column("id", Int32.self, primaryKey: true)
    let course = Column("course", String.self)
    let grade = Column("grade", Int32.self)
}

We will add a second table called courses:

class Courses: Table {
    let tableName = "Courses"
    let name = Column("name", String.self, primaryKey: true)
    let credit = Column("credit", Int32.self)
    let teacher = Column("teacher", String.self)
}
let courses = Courses()

We can add a foreign key to Grades that references a column in another table:

let grades = Grades().foreignKey(grades.course, references: courses.name)

Create a multi-column primary key (if not set in the column as for Grades.id)

grades.primaryKey(grades.id, grades.course)

Create the table in the database:

courses.create(connection: connection) { result in
     guard result.success else {
        print("Failed to create table: \(result.asError?)")
     }
    ...
}

Indices

You can manage indices with Swift-Kuery in the following way:

let index = Index("index", on: grades, columns: [grades.id, desc(grades.grade)])
index.create(connection: connection) { result in ... }
...
index.drop(connection: connection) { result in ... }

Migration

Swift-Kuery has a class Migration to help with migrations between two versions of a table.

Suppose we have a table MyTable in our application. The suggested usage is to keep versions of the table classes somewhere in the application code:

public class MyTable_v0: Table {
    let a = Column("a", ...)
    let b = Column("b", ...)
    let tableName = "MyTable"
}

public class MyTable_v1: Table {
    let b = Column("b", ...)
    let c = Column("c", ...)
    let tableName = "MyTable"
}

Use a typealias to refer to the current version of the table class in the application:

typealias MyTable = MyTable_v0
let t = MyTable()
let q = Select(from t)
...

The migration code from v0 to v1 should be something like this:

let t0 = MyTable_v0()
let t1 = MyTable_v1()
let migration0 = Migration(from: t0, to: t1, using: connection)
migration0.alterTableAdd(column: t1.c) { result in ... }

You can also execute raw alterations, if needed:

let dropColumnQuery = "ALTER TABLE " + t1.tableName + " DROP COLUMN " + t0.a.name
connection.execute(dropColumnQuery) { result in ... }

Query Examples

In the following section, we will provide an example SQL query and show you how to build and execute the same query in Swift using Swift-Kuery.

Classes used in the examples:

These examples we will use the following two tables:

class T1 {
  let tableName = "t1"
  let a = Column("a")
  let b = Column("b")
}

class T2 {
  let tableName = "t2"
  let c = Column("c")
  let b = Column("b")
}

 

SELECT * FROM t1;

This query will select all results from the table. The example below shows how to execute this query including the boilerplate code:

let t1 = T1()

let query = Select(from: t1)

pool.getConnection() { connection, error in
    guard let connection = connection else {
        // Handle error
        return
    }
    query.execute(connection) { queryResult in
        guard let resultSet = queryResult.asResultSet else {
            // Handle error
            return
        }
        resultSet.getColumnTitles() { titles, error in
            guard let titles = titles else {
                // Handle error
                return
            }
            //Process titles
            resultSet.forEach() { row, error in
                guard let row = row else {
                    // Processed all results
                    return
                }
                // Process row
            }
        }
    }
}

The following examples show more complex queries, which can be substituted into the the above boilerplate.  

SELECT a, b FROM t1
WHERE (a LIKE '%b' OR a = 'apple') AND b > 5
ORDER BY b ASC, a DESC
OFFSET 5;

let query = Select(t1.a, t1.b, from: t1)
  .where((t1.a.like("b%") || t1.a == "apple") && t1.b > 5)
  .order(by: .ASC(t1.b), .DESC(t1.a))
  .offset(5)

 

SELECT UCASE(a) AS name FROM t1
WHERE b >= 0
GROUP BY a
HAVING SUM(b) > 3
ORDER BY a DESC;

let query = Select(ucase(t1.a).as("name"), from: t1)
  .where(t1.b >= 0)
  .group(by: t1.a)
  .having(sum(t1.b) > 3)
  .order(by: .DESC(t1.a))

 

INSERT INTO t1
VALUES ('apple', 10), ('apricot', 3), ('banana', 17);

let query = Insert(into: t1, rows: [["apple", 10], ["apricot", 3], ["banana", 17]])

 

INSERT INTO t1
VALUES ('apple', 10);

let query = Insert(into: t1, values: "apple", 10)

 

INSERT INTO t1 (a, b)
VALUES ('apricot', '3');

let query = Insert(into: t1, valueTuples: (t1.a, "apricot"), (t1.b, "3"))

 

INSERT INTO t1 (a, b)
VALUES ('apricot', '3');

let query = Insert(into: t1, columns: [t1.a, t1.b], values: ["apricot", 3])

 

UPDATE t1 SET a = 'peach', b = 2
WHERE a = 'banana';

let query = Update(t1, set: [(t1.a, "peach"), (t1.b, 2)])
  .where(t1.a == "banana")

 

SELECT * FROM t1 AS left
LEFT JOIN t2 AS right
ON left.b = right.b;

let t1 = T1()
let t2 = T2()

let leftTable = t1.as("left")
let rightTable = t2.as("right")
let query = Select(from: leftTable)
  .leftJoin(rightTable)
  .on(leftTable.b == rightTable.b)

 

SELECT * FROM t1
JOIN t2
USING (b);

let query = Select(from: t1)
  .join(t2)
  .using(t1.b)

 

Queries with parameters:

Note: Named parameters are supported for all databases, even for those that do not support named parameters (e.g. PostgreSQL).

INSERT INTO t1
VALUES (@0,@1);

let query = Insert(into: t1, values: Parameter(), Parameter())

connection.execute(query: query, parameters: "banana", 28) { queryResult in
  // Process result
}

 

INSERT INTO t1
VALUES (@fruit,@number);

let query = Insert(into: t1, values: Parameter("fruit"), Parameter("number"))

connection.execute(query: query, parameters: ["number" : 28, "fruit" : "banana"]) { queryResult in
  // Process result
}

 

It is possible to insert NULL values using parameters:  

connection.execute(query: query, parameters: ["number" : 28, "fruit" : nil]) { queryResult in
  // Process result
}

 

Raw query:

connection.execute("CREATE TABLE myTable (a varchar(40), b integer)") {  queryResult in
  // Process result
}

 

SELECT LEFT(a, 2) as raw FROM t1
WHERE b >= 0 GROUP BY a
HAVING sum(b) > 3
ORDER BY a DESC;

let query = Select(RawField("LEFT(a, 2) as raw"), from: t1)
  .where("b >= 0")
  .group(by: t1.a)
  .having("sum(b) > 3")
  .order(by: .DESC(t1.a))

 

SELECT * FROM t1
WHERE b >= ANY (SELECT b FROM t2);

let query = Select(from: t1)
  .where(t1.b >= any(Select(t2.b, from: t2)))

 

SELECT * FROM t1
WHERE NOT EXISTS (SELECT * FROM t2 WHERE b < 8);

let query = Select(from: t1)
  .where(notExists(Select(from: t2).where(t2.b < 8)))

 

SELECT c FROM t2 GROUP BY c
HAVING SUM(b) NOT IN (SELECT b FROM t1 WHERE a = 'apple');

let query = Select(t2.c, from: t2)
    .group(by: t2.c)
    .having(sum(t2.b).notIn(Select(t1.b, from: t1).where(t1.a == "apple")))

List of plugins

API Documentation

For more information visit our API reference.

Community

We love to talk server-side Swift, and Kitura. Join our Slack to meet the team!

License

This library is licensed under Apache 2.0. Full license text is available in LICENSE.

swift-kuery's People

Contributors

andrew-lees11 avatar bdhernand avatar bfleischer avatar dannys42 avatar davidde94 avatar dingwilson avatar djones6 avatar drewmcarthur avatar enriquel8 avatar helenmasters avatar ianpartridge avatar irar2 avatar jaredanderton avatar kilnerm avatar kyemaloy97 avatar mbarnach avatar na-gupta avatar naithar avatar nocturnalsolutions avatar quanvo87 avatar shihabmehboob avatar shmuelk avatar wafflespeanut avatar

Stargazers

 avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar

Watchers

 avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar  avatar

swift-kuery's Issues

QueryFilterProtocol custom function name

Is it possible to implement the possibility to have custom function names for QueryFilterProtocol?
For example my query require a where with UNIX_TIMESTAMP(column) and I can not achieve this now...

Column needs to know its Table

In order to implement JOIN and table alias, Column needs to know its Table.

At the moment Table is a protocol, and Column is a struct, and the user is supposed to define tables as following:

struct T : Table {
    var name = "mytable"
    var a = Column("a")
    var b = Column("b")
}
let t = T()

This allows us a nice usage of t.a when we want to address column a of table t.
But we can't set column's table this way.

The solution we thought of is to make both Table and Column classes, and access table's columns from Table.init using Mirror (Column needs to be a class in order to allow its declaration inside tables with let and not var without getting run time errors):

class Table {
    var name : String {
        return ""
    }

    init() {
        let mirror = Mirror(reflecting: self)
        for child in mirror.children {
            if let ch = child.value as? Column {
                ch.table = self
            }
        }
    }
}

class Column {
    var name: String
    var table: Table?

    init(_ name: String) { self.name = name }
}

class T : Table {
    override var name : String {
        return "mytable"
    }

    let a = Column("a")
    let b = Column("b")
    let garbage = "garbage"
}

let t = T()
print(t.a.table!.name) // prints "mytable"

Thoughts?

Swift-Kuery should throw an exception before it attempts to execute poorly formed SQL

We forgot to change

class A: Table {
   let name = "A"
}

to:

class A: Table {
   let tableName = "A"
}

when we did an insert, it attempted to execute:

INSERT into (id, ...) VALUES (..., )

Notice the missing tableName. We had to read the SQL error description in order to find out what was wrong. I am wondering if we can do some Swift API language tricks to ensure that this cannot be the case.

For instance, make tableName a required property in a protocol that Table uses.

var tableName: String { get }

By default add and use array args rather than var args for filters

Sorry the title is a bit hard to explain but currently to do an IN filter one must use something like .where(column.id.in("a", "b", "c")). It would be great to be able to also do .where(column.id.in(["a", "b", "c"])).

While raw SQL may be better suited to var args most users will be feeding in ids from previous selects / user input etc and it's impossible to turn a Swift array into a var arg array for calling a function.

WITH clauses for SELECT

Are WITH clauses for select query in the list of features to be implemented or it's something that expected to be covered with Raw queries?

Implementing a sync access for database or at the least asRows property as desribed in #4 would certainly help in creating a workaround for missing clause as currently without Raw query implementation of workaround leads to callback hell.

How to use a single object for both table and object representation?

Currently, I have a BookTable class and a Book struct. The BookTable is used just to expose the schema to Kuery. Bookstore

Instead of having a BooksTable class and a Book struct, I think I want to have only a Book struct. I want to define something like this:

struct Book: Table {

    let name = "books"

    let bookIDColumn = Column("book_id")
    let titleColumn = Column("title")
    let ISBNColumn = Column("isbn")
    
   let bookID: Int
   let title: String
   let ISBN: String
}

However, of course, I can't do that because Table is a class- and Kuery gets the builder pattern working through inheritance. I don't have a solution to this problem, necessarily. But I would like to use a value-type for Book if possible.

SQLite syntax error with HAVING

=======SELECT left(a, 2) as raw FROM tableSelectOSX WHERE b >= 0 GROUP BY tableSelectOSX.a HAVING sum(b) > 3 ORDER BY tableSelectOSX.a DESC=======
Error in query:  near "(": syntax error

Describe column schema with Kuery?

I have studied how SQLAlchemy works in order to describe a table and its columns:

>>> User.__table__ 
Table('users', MetaData(bind=None),
            Column('id', Integer(), table=<users>, primary_key=True, nullable=False),
            Column('name', String(), table=<users>),
            Column('fullname', String(), table=<users>),
            Column('password', String(), table=<users>), schema=None)

It specifies the column title, the data type, the table it refers to, and the default values. I think having some of this could help with:

  1. The creation of the table directly from our Table description.
  2. Help us later create the mapping from the Table to a Swift struct or class automatically for users. Potentially for a future ORM library that uses Swift-Kuery, for instance.

So in Swift, I was thinking something like this:

class Users: Table {

   let id = Column(name: "id", type: .integer, isPrimaryKey: true, isNull: false)
   let name= Column(name: "name", type: .text)
   let fullName = Column(name: "fullname", type: .text)
   let password = Column(name: "password", type: .text) 
}

where types could be:

enum SQLDataType {
   case integer
   case text
   // ...
}

Document Swift-Kuery has no paramenter binding and is not safe from SQL injection.

I just did a quick experiment and came to the conclusion that it's very easy to inject SQL using Swift-Kuery. Given SQL injection is a major security vulnerability I suggest it be documented as such until such time it is resolved:

public class DocumentsTable : Table {
    let tableName = "document"
    let sequence = Column("sequence")
    let id = Column("id")
    let type = Column("type")
    let json = Column("json")
}
public let docs = DocumentsTable()

let builder = QueryBuilder()

let statement = Select(fields: [docs.id, docs.type, docs.json], from: docs).where(docs.id.in("a'); DELETE FROM docs WHERE id IN ('b', 'c"))
print(try statement.build(queryBuilder: builder))

Emits:

SELECT document.id, document.type, document.json FROM document WHERE document.id IN ('a'); DELETE FROM docs WHERE id IN ('b', 'c')

Some drivers may detect the dual statement and prevent it but many would not.

Connection management?

Right now I have for each Kitura handler, creating a new PostgreSQL connection, connecting to it, then servicing the request. I would like to perhaps use a single connection object that can do a reconnect only if needed (in case the connection has been lost for some reason). Do do that, I need connection status. Perhaps the result of running:

ConnStatusType PQstatus(const PGconn *conn);

https://www.postgresql.org/docs/9.1/static/libpq-status.html

Do we have plans for these find of connection management policies?

SQLite does not support FULL JOIN

=======SELECT * FROM table1JoinOSX AS t1 FULL JOIN table2JoinOSX AS t2 USING (b)=======
Error in query:  RIGHT and FULL OUTER JOINs are not currently supported

Change Connection API to be synchronous

The execute query functions will look like this:

   /// Execute a query.
   ///
   /// - Parameter query: The query to execute. 
   /// - Returns: An instance of QueryResult representing the result of the query execution.
  func execute(query: Query) -> QueryResult

Transaction related functions will be changed in the same way:

    /// Start a transaction.
    ///
    /// - Returns:  An instance of QueryResult representing the result of the execution of start transaction command.
    func startTransaction() -> QueryResult

We can also throw errors instead of returning them inside QueryResult.


ResultFetcher will be synchronous only, i.e.

    /// Fetch the next row of the query result. This function is non-blocking.
    ///
    /// - Parameter callback: A callback to call when the next row of the query result is ready.
    func fetchNext(callback: ([Any?]?) ->())

will be removed.

Support nil input parameters

Could we change the Connection execute APIs so parameter values are optional (parameters: [Any?] and parameters: [String: Any?]) so we can support setting input parameters to null.

Build error when building within Xcode or AppCode

I have an app that uses SwiftKuery. The app builds successfully from the command line:

$ swift build

However, when I try to build from within Xcode (or AppCode), I get the following errors:

Use of undeclared type 'IndexColumn'  Column.swift
Use of undeclared type 'SQLDataType'  Column.swift

I use Xcode 8.3.2

Support named parameters for all databases

Some databases or their SDKs don't support named parameters.

We can add a scan (similar to Utils.updateParameterNumbers) of all queries we build to check if a query contains named parameters while they are not supported. This utility function will replace named parameters with numbered parameters and return a mapping [parameter name : parameter number].

We can call this function from an extension to Connection, that will implement execute with named parameters. Something along these lines:

public extension Connection {
    func execute(query: Query, parameters: [String:Any?], onCompletion: @escaping ((QueryResult) -> ())) {
        do {
            let databaseQuery = try query.build(queryBuilder: queryBuilder)
            let (convertedQuery, namedToNumbered) = Utils.convertNamedParametersToNumbered(query: databaseQuery, queryBuilder: queryBuilder)
            var numberedParameters: [Any?] = Array(repeating: nil, count: parameters.count)
            for (parameterName, parameterValue) in parameters {
                if let number = namedToNumbered[parameterName] {
                    numberedParameters[number] = parameterValue
                }
                else {
                    // error
                }
            }
            execute(convertedQuery, parameters: numberedParameters, onCompletion: onCompletion)
        }
        catch  { //...
        }
    }
}

This will require adding QueryBuilder to Connection.

AggregateFunction custom function name

Can you change the AggregateFunction implementation to work with custom function names? My solution is :
/**
Copyright IBM Corporation 2016, 2017

Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at

http://www.apache.org/licenses/LICENSE-2.0

Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.
*/

// MARK: AggregateColumnExpression

/// An expression containing an aggregate function applied on a column.
public struct AggregateColumnExpression: Field {

/// The alias of the field.
public var alias: String?

/// The aggregate function to apply.
public private (set) var function: AggregateFunction
    
init(_ function: AggregateFunction) {
    self.function = function
}

/// Build the query component using `QueryBuilder`.
///
/// - Parameter queryBuilder: The QueryBuilder to use.
/// - Returns: A String representation of the query component.
/// - Throws: QueryError.syntaxError if query build fails.
public func build(queryBuilder: QueryBuilder) throws -> String {
    var result = try function.build(queryBuilder: queryBuilder)
    if let alias = alias {
        result += " AS " + Utils.packName(alias, queryBuilder: queryBuilder)
    }
    return result
}

/// An enumeration of the supported aggregate functions that can applied on a column.
public enum AggregateFunction {
    /// The SQL AVG function.
    case avg(field: Field)
    /// The SQL MAX function.
    case max(field: Field)
    /// The SQL MIN function.
    case min(field: Field)
    /// The SQL SUM function.
    case sum(field: Field)
    /// The SQL LAST function.
    case last(field: Field)
    /// The SQL FIRST function.
    case first(field: Field)
    /// The SQL COUNT function.
    case count(field: Field)
    /// The SQL COUNT DISTINCT function.
    case countDistinct(field: Field)
    /// The SQL UCASE function.
    case ucase(field: Field)
    /// The SQL LCASE function.
    case lcase(field: Field)
    /// The SQL ROUND function.
    case round(field: Field, to: Int)
    /// The SQL MID function.
    case mid(field: Field, start: Int, length: Int)
    /// The SQL LEN function.
    case len(field: Field)
    /// A SQL custom function.
    case custom(name: String, field: Field)
    
    /// Build the query component using `QueryBuilder`.
    ///
    /// - Parameter queryBuilder: The QueryBuilder to use.
    /// - Returns: A String representation of the query component.
    /// - Throws: QueryError.syntaxError if query build fails.
    public func build(queryBuilder: QueryBuilder) throws -> String {
        switch self {
        case .avg(let field):
            return try "AVG(" + field.build(queryBuilder: queryBuilder) + ")"
        case .max(let field):
            return try "MAX(" + field.build(queryBuilder: queryBuilder) + ")"
        case .min(let field):
            return try "MIN(" + field.build(queryBuilder: queryBuilder) + ")"
        case .sum(let field):
            return try "SUM(" + field.build(queryBuilder: queryBuilder) + ")"
        case .last(let field):
            return try "LAST(" + field.build(queryBuilder: queryBuilder) + ")"
        case .first(let field):
            return try "FIRST(" + field.build(queryBuilder: queryBuilder) + ")"
        case .count(let field):
            return try "COUNT(" + field.build(queryBuilder: queryBuilder) + ")"
        case .countDistinct(let field):
            return try "COUNT(DISTINCT(" + field.build(queryBuilder: queryBuilder) + "))"
        case .ucase(let field):
            return try queryBuilder.substitutions[QueryBuilder.QuerySubstitutionNames.ucase.rawValue] + "(" + field.build(queryBuilder: queryBuilder) + ")"
        case .lcase(let field):
            return try queryBuilder.substitutions[QueryBuilder.QuerySubstitutionNames.lcase.rawValue] + "(" + field.build(queryBuilder: queryBuilder) + ")"
        case .round(let field, let decimal):
            return try "ROUND(" + field.build(queryBuilder: queryBuilder) + ", \(decimal))"
        case .mid(let field, let start, let length):
            return try "MID(" + field.build(queryBuilder: queryBuilder) + ", \(start), \(length))"
        case .len(let field):
            return try "LEN(" + field.build(queryBuilder: queryBuilder) + ")"
        case .custom(let name, let field):
            return try "\(name)(" + field.build(queryBuilder: queryBuilder) + ")"
        }
    }
}

}

// MARK Global functions

/// Create an AggregateColumnExpression using the AVG function.
///
/// - Parameter field: The Field to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func avg(_ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.avg(field: field))
}

/// Create an AggregateColumnExpression using the MAX function.
///
/// - Parameter field: The Field to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func max(_ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.max(field: field))
}

/// Create an AggregateColumnExpression using the MIN function.
///
/// - Parameter field: The Field to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func min(_ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.min(field: field))
}

/// Create an AggregateColumnExpression using the SUM function.
///
/// - Parameter field: The Field to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func sum(_ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.sum(field: field))
}

/// Create an AggregateColumnExpression using the LAST function.
///
/// - Parameter field: The Field to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func last(_ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.last(field: field))
}

/// Create an AggregateColumnExpression using the FIRST function.
///
/// - Parameter field: The Field to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func first(_ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.first(field: field))
}

/// Create an AggregateColumnExpression using the COUNT function.
///
/// - Parameter field: The Field to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func count(_ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.count(field: field))
}

/// Create an AggregateColumnExpression using the COUNT DISTINCT function.
///
/// - Parameter field: The Field to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func countDistinct(_ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.countDistinct(field: field))
}

/// Create a AggregateColumnExpression using the LEN function.
///
/// - Parameter field: The AggregateColumnExpression to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func len(_ field: AggregateColumnExpression) -> AggregateColumnExpression {
return AggregateColumnExpression(.len(field: field))
}

/// Create a AggregateColumnExpression the using UCASE function.
///
/// - Parameter field: The AggregateColumnExpression to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func ucase(_ field: AggregateColumnExpression) -> AggregateColumnExpression {
return AggregateColumnExpression(.ucase(field: field))
}

/// Create a AggregateColumnExpression using the LCASE function.
///
/// - Parameter field: The AggregateColumnExpression to apply the function on.
/// - Returns: An instance of AggregateColumnExpression.
public func lcase(_ field: AggregateColumnExpression) -> AggregateColumnExpression {
return AggregateColumnExpression(.lcase(field: field))
}

/// Create a AggregateColumnExpression using the ROUND function.
///
/// - Parameter field: The AggregateColumnExpression to apply the function on.
/// - Parameter to: The decimal to round the values to.
/// - Returns: An instance of AggregateColumnExpression.
public func round(_ field: AggregateColumnExpression, to decimal: Int) -> AggregateColumnExpression {
return AggregateColumnExpression(.round(field: field, to: decimal))
}

/// Create a AggregateColumnExpression using the MID function.
///
/// - Parameter field: The AggregateColumnExpression to apply the function on.
/// - Parameter start: The starting position for the text extraction.
/// - Parameter length: The number of characters to return.
/// - Returns: An instance of AggregateColumnExpression.
public func mid(_ field: AggregateColumnExpression, start: Int, length: Int) -> AggregateColumnExpression {
return AggregateColumnExpression(.mid(field: field, start: start, length: length))
}

/// Create a AggregateColumnExpression using a custom name function.
///
/// - Parameters:
/// - name: The name of the custom function.
/// - field: The argument of the custom function.
/// - Returns: An instance of AggregateColumnExpression.
public func custom(name: String, _ field: Field) -> AggregateColumnExpression {
return AggregateColumnExpression(.custom(name: name, field: field))
}

How to handle operations when there is no connection to the database?

The expected flow is as following:

let connection = PostgreSQLConnection(/* connection parameters */)
connection.connect()
connection.execute(query)

i.e., create a connection instance, connect it to the database, execute queries.

What is the best behavior when the user tries to do something on a connection that is not connected to a database? E.g.:

let connection = PostgreSQLConnection()
connection.execute(query)

or even

connection.closeConnection()
connection.execute(query)

Should we fail or (re)connect to the database?

This should be the same behavior as in connection pooling (#16).

Can we simplify the asRows property?

Right now, the asRows property takes the following signature:

public var asRows: ([String], [[Any?]])? 

I propose we change it to:

public var asRows: [[String: Any]]

Reasons:

  • Would make it easier to transform the rows into corresponding objects.
  • Would more close match the JSON signatures
  • I don't understand why the returned value could be nil. If we want to return an NULL from the database, can't we create a new enum case for that?

Alternative

enum SQLValue {
   case double(Double)
   case null
   // ...

public var asRows: [[String: SQLValue]]
}

How to update if already exists, insert otherwise pattern?

I would like to update a record if it already exists, but insert a new record if it doesn't. I currently do this in PostgreSQL to accomplish that:

let updateSQL = "UPDATE \(Config.tableName) set status=\(status.rawValue), build_time=\(buildTime) WHERE url='\(url)'"
let insertSQL = "INSERT into \(Config.tableName) (url, version, status, build_time) select '\(url)','\(version)',\(status.rawValue),\(buildTime) WHERE NOT EXISTS ( SELECT url from \(Config.tableName) where url='\(url)' and version='\(version)')"

Is there any way to express this in Kuery?

Multiple JOIN not supported

Atm, creating a query with multiple join statements, results in error Multiple joins.
Will this be changed or is this on purpose?

Also, is contribution on this project's stage acceptable?

Provide support for monitoring queries

In order to be able to do complete monitoring of a deployed application, its also important to be able to monitor database calls for to understand their performance and whether errors are occurring.

The basic data that would be needed is the equivalent for what we collect for MySQL queries on Node.js in 'appmetrics':
https://www.npmjs.com/package/appmetrics

Event: 'mysql'
Emitted when a MySQL query is made using the mysql module.

* data (Object) the data from the MySQL query:
  * time (Number) the milliseconds when the MySQL query was made. This can be converted to a Date using new Date(data.time).
  * query (String) the query made of the MySQL database.
  * duration (Number) the time taken for the MySQL query to be responded to in ms.

Additionally in the future we may also want the ability to be able to insert fault injection, and circuit breaking functionality, etc.

Casting result to Int vs Int32

Hi,

thank you for the wonderful library but I have a question regarding casting result to Int and Int32.

I have the following table definition:

import SwiftKuery
import SwiftKueryPostgreSQL

class Tokens: Table {
    let tableName = "tokens"
    let id = Column("id", String.self, primaryKey: true, notNull: true, unique: true)
    let userId = Column("userId", String.self, notNull: true)
    let createdAt = Column("createdAt", Int64.self, notNull: true)
    var updatedAt = Column("updatedAt", Int64.self, notNull: true)
    var idle = Column("idle", Int.self, notNull: true)
}

and I execute this query

        let getTokenById =
            Select(fields: [tokens.id, tokens.userId, tokens.createdAt, tokens.updatedAt, tokens.idle], from: [tokens])
                .where(tokens.id == id)
                .limit(to: 1)
        connection.execute(query: getTokenById) { result in
            if let row = result.asRows?.first {
                guard let id = row["id"] as? String,
                        let userId = row["userid"] as? String,
                        let createdAt = row["createdat"] as? Int64,
                        let updatedAt = row["updatedat"] as? Int64,
                        let idle = row["idle"] as? Int else {
                    return
                }
                // Use values defined above
            }
        }

Now the problem is that assignment to idle variable fails. If I cast to Int32 everything works fine
(let idle = row["idle"] as? Int32 else { - this one works fine)

I just want to know if the problem is in Swift, Kuery or I'm doing something wrong?

Subquery returns no rows on SQLite

In TestSubquery.swift:

Select(from: t).where((-7).in(Select(t.b, from: t).where(t.b == -1)))

is generating:

SELECT * FROM tableSubquery WHERE -7 IN (SELECT tableSubquery.b FROM tableSubquery WHERE tableSubquery.b = -1)

however on SQLite this crashes because rows is nil ("SELECT returned no rows").

I'm confused though, because as far as I can see the subquery should return no rows because t.b is never -1?

No such column `false` with SQLite

Select(from: t).where(false.notIn(Parameter(), Parameter()))

produces:

=======SELECT * FROM tableSubquery WHERE false NOT IN (?1, ?2)=======
Error in query:  no such column: false

Memory leak in Swift-Kuery Postgres

After running the Postgres Swift-Kuery implementations of the performance benchmarks in https://github.com/djones6/Swift-TechEmpower/tree/master/kitura noticed the memory was constantly increasing over time.
Valgrind output for a run is below:

| ->69.25% (16,420,864B) 0x5483D7E: ??? (in /usr/lib/libpq.so.5.6)
| | ->69.25% (16,420,864B) 0x547B856: PQgetResult (in /usr/lib/libpq.so.5.6)
| |   ->69.25% (16,420,864B) 0x5CFDA5: function signature specialization <Arg[0] = Owned To Guaranteed and Exploded, Arg[1] = Owned To Guarante
ed> of SwiftKueryPostgreSQL.PostgreSQLConnection.(processQueryResult in _95DE2E52192B2721963949C698E38D03) (query : Swift.String, onCompletion
: (SwiftKuery.QueryResult) -> ()) -> () (in /home/awishart/git/Swift-TechEmpower-fork/kitura/.build/release/TechEmpowerKuery)
| |     ->69.25% (16,420,864B) 0x5CC826: SwiftKueryPostgreSQL.PostgreSQLConnection.execute (query : SwiftKuery.Query, onCompletion : (SwiftKuer
y.QueryResult) -> ()) -> () (in /home/awishart/git/Swift-TechEmpower-fork/kitura/.build/release/TechEmpowerKuery)
| |       ->69.25% (16,420,864B) 0x5C9DAE: protocol witness for SwiftKuery.Connection.execute (query : SwiftKuery.Query, onCompletion : (SwiftK
uery.QueryResult) -> ()) -> () in conformance SwiftKueryPostgreSQL.PostgreSQLConnection : SwiftKuery.Connection in SwiftKueryPostgreSQL (in /ho
me/awishart/git/Swift-TechEmpower-fork/kitura/.build/release/TechEmpowerKuery)
| |         ->69.25% (16,420,864B) 0x57DBF0: function signature specialization <Arg[1] = Owned To Guaranteed> of SwiftKuery.ConnectionPoolConne
ction.execute (query : SwiftKuery.Query, onCompletion : (SwiftKuery.QueryResult) -> ()) -> () (in /home/awishart/git/Swift-TechEmpower-fork/kitura/.build/release/TechEmpowerKuery)
| |           ->69.25% (16,420,864B) 0x57D3FC: SwiftKuery.ConnectionPoolConnection.execute (query : SwiftKuery.Query, onCompletion : (SwiftKuery.QueryResult) -> ()) -> () (in /home/awishart/git/Swift-TechEmpower-fork/kitura/.build/release/TechEmpowerKuery)
| |             ->69.25% (16,420,864B) 0x554AFE: protocol witness for SwiftKuery.Connection.execute (query : SwiftKuery.Query, onCompletion : (SwiftKuery.QueryResult) -> ()) -> () in conformance SwiftKuery.ConnectionPoolConnection : SwiftKuery.Connection in SwiftKuery (in /home/awishart/git/Swift-TechEmpower-fork/kitura/.build/release/TechEmpowerKuery)```

Support many-to-many mapping

I have tables for books and authors. I also have a join table which allows for a many-to-many join of tables. For instance, books can have several authors and authors can have several books. I want to do the equivalent to:

SELECT * from books, authors, book_author 
WHERE books.book_id=book_author.book_id 
  AND authors.author_id=book_author.author_id 
  AND authors.name=<author>;

How can I do this? I want something like this, however it's still not clear what the join is done on:

        let booksTable = BooksTable()
        let authorsTable = AuthorsTable()
        let bookAuthorsTable = BookAuthorsTable()

        return Select(from: booksTable)
            .join(on: bookAuthorsTable.bookID)
            .join(on: authorsTable.authorID)
            .on(booksTable.bookID == bookAuthorsTable.bookID)
            .on(authorsTable.authorID == bookAuthorsTable.authorID)
            .where(authorsTable.authorName == author)

Support database specific extensions

There are several keywords supported by Swift-Kuery that are not supported by some databases. At the moment we are aware of the following:

keyword PostgreSQL SQLite MySQL DB2
RETURNING yes no no no
ANY (subquery) yes no yes
OFFSET without LIMIT yes no no
FULL JOIN yes no no
RIGHT JOIN yes no yes

We propose to deal with each problem in a different way, because we are trying to find a trade-off between supporting as much as possible and still keeping Swift-Kuery reasonable:

  • RETURNING - remove the current support. Allow RETURNING using raw, i.e. add raw(String) method to Insert and Update that will append the contents of the String to the query
  • ANY - add a flag to QueryBuilder to indicate if ANY is supported, and throw an error during build of a query with ANY if it is not
  • OFFSET - don't allow OFFSET without LIMIT
  • JOINs - allow raw type of JOIN in Join enumeration

It is also possible to insert queries in raw queries, for example to support RETURNING in DB2:

let insert = Insert(...)
let insertDescription = connection.descriptionOf(insert)
let rawQuery = "SELECT * FROM FINAL table (\insertDescription)"
connection.execute(rawQuery) 

SQLite returns nil rows instead of empty array

=======CREATE TABLE tableUpdateOSX (a varchar(40), b integer)=======
Success
=======INSERT INTO tableUpdateOSX VALUES ('apple', 10), ('apricot', 3), ('banana', 17), ('apple', 17), ('banana', -7), ('banana', 27)=======
Success
=======SELECT * FROM tableUpdateOSX=======
a          b          
apple      10         
apricot    3          
banana     17         
apple      17         
banana     -7         
banana     27         
=======UPDATE tableUpdateOSX SET a = 'peach', b = 2 WHERE tableUpdateOSX.a = 'banana'=======
Success
=======UPDATE tableUpdateOSX SET a = 'peach', b = 2 WHERE tableUpdateOSX.a = 'apple'=======
Success
=======SELECT tableUpdateOSX.a, tableUpdateOSX.b FROM tableUpdateOSX WHERE tableUpdateOSX.a = 'banana'=======
Success
fatal error: unexpectedly found nil while unwrapping an Optional value

The crash is because rows is nil, not the empty array. The QueryResult is successNoData.

fatal: No url found for submodule path 'Kitura-Build' in .gitmodules

Not sure what the root cause of this error, but it's been replicated in our projects. @davidungar , @king33 , and me. I was able to get past it by running swift build multiple times, I believe.

The error is the following:

[Flashy:~/code/postBook] ungar% cd Bookstore/
[Flashy:~/code/postBook/Bookstore] ungar% ls
Database/	Package.swift	Procfile	README.md	Sources/	Tests/		manifest.yml
[Flashy:~/code/postBook/Bookstore] ungar% swift package generate-xcodeproj
Cloning https://github.com/IBM-Swift/HeliumLogger.git
HEAD is now at c974057 Update to Swift 3.0.1 (#35)
Resolved version: 1.1.0
Cloning https://github.com/IBM-Swift/LoggerAPI.git
HEAD is now at c64ce64 Merge pull request #16 from IBM-Swift/issue_832
Resolved version: 1.1.0
Cloning https://github.com/IBM-Swift/Kitura.git
HEAD is now at d578faa IBM-Swift/Kitura#836 Switch out deprecated server.listen calls and remove now redundant sleep calls (#844)
Resolved version: 1.1.1
Cloning https://github.com/IBM-Swift/Kitura-net.git
HEAD is now at 0e81e12 IBM-Swift/Kitura#836 Catch and log errors in socket.acceptClientConne… (#139)
Resolved version: 1.1.1
Cloning https://github.com/IBM-Swift/BlueSocket.git
HEAD is now at 61d47f7 Update to latest (11/1) toolchain.
Resolved version: 0.11.39
Cloning https://github.com/IBM-Swift/CCurl.git
HEAD is now at 3cfb752 Add header callback helper function (#9)
Resolved version: 0.2.3
Cloning https://github.com/IBM-Swift/CHTTPParser.git
HEAD is now at 429eff6 Merge pull request #7 from ianpartridge/master
Resolved version: 0.3.0
Cloning https://github.com/IBM-Swift/BlueSSLService.git
HEAD is now at a6219f9 Return zero on macOS when encountering an "errSSLClosedGraceful" error on a read rather than throwing an error.
Resolved version: 0.11.54
Cloning https://github.com/IBM-Swift/SwiftyJSON.git
HEAD is now at ba99cbf Merge pull request #26 from IBM-Swift/issue_832
Resolved version: 15.0.0
Cloning https://github.com/IBM-Swift/Kitura-TemplateEngine.git
HEAD is now at 4fe7829 Support Swift 3.0.1 (#9)
Resolved version: 1.1.0
Cloning https://github.com/rfdickerson/Swift-Kuery-PostgreSQL
/usr/bin/git clone --recursive --depth 10 https://github.com/rfdickerson/Swift-Kuery-PostgreSQL /Volumes/Flashy_IBM/Users/IBM/code/postBook/Bookstore/Packages/Swift-Kuery-PostgreSQL
Cloning into '/Volumes/Flashy_IBM/Users/IBM/code/postBook/Bookstore/Packages/Swift-Kuery-PostgreSQL'...
fatal: No url found for submodule path 'Kitura-Build' in .gitmodules

error: Failed to clone https://github.com/rfdickerson/Swift-Kuery-PostgreSQL to /Volumes/Flashy_IBM/Users/IBM/code/postBook/Bookstore/Packages/Swift-Kuery-PostgreSQL

Connection does not handle SQLite

The init in Connection.swift can only handle the host name and the port whereas, in SQLite in can either be in memory or a file path

Support for fetching N rows at a time instead of all together

Does Swift-Kuery support pagination? For example, suppose you have a query which returns 1,000 results.

You might want a way to iterate through chunks of results using a cursor pattern. This would avoid loading all 1,000 results into memory at once.

Change "name" to "tableName" in Table?

I was wondering if we can change name in the Table to tableName, which could prevent chance of collisions over the name that the users could select by chance.

I noticed bookshelfjs does something similar, using tableName instead.

Return a Sequence rather than an in-memory array?

I was wondering if we could return a Sequence<Record> where Record is that that result set that we define in #4 . What this would do, would be that you can have access to the results one at a time, using some of the things we are doing #11 as the mechanism.

To the user, they would have access to Sequence-like behavior, even though it's lazily evaluated. e.x.:

let results = connection.execute("SELECT * FROM books")

let totalBookPrice = results.reduce(0,  { $0["price] + $1 })

You could imagine how expensive that would be to do if it was all in main memory (where there are thousands of books each with dozens of fields), but here- we just deal with price. Haha- I realize you can do that in SQL with the SUM function- so maybe my example isn't a good one- but you can imagine doing some complex business side logic in this way.

Support efficient multi row inserts/updates

Could we add Connection APIs to take multiple parameter sets as follows:

func execute(query: Query, parametersArray: [[Any?]], onCompletion: @escaping ((QueryResult) -> ()))

func execute(query: Query, parametersArray: [[String: Any?]], onCompletion: @escaping ((QueryResult) -> ()))

func execute(_ raw: String, parametersArray: [[Any?]], onCompletion: @escaping ((QueryResult) -> ()))

func execute(_ raw: String, parametersArray: [[String: Any?]], onCompletion: @escaping ((QueryResult) -> ()))

This will let us do more efficient prepared statement inserts/updates/deletes where we prepare the statement once, and execute it multiple times using different bindings.

Perhaps we only support this for inserts/updates/deletes and not for selects?

We could support selects as well, but that will need changes to QueryResult and ResultSet to be able to return multiple results, and may be more messy than it's worth.

SQLite syntax error

=======SELECT UPPER(tableSelectOSX.a) AS case, tableSelectOSX.b FROM tableSelectOSX WHERE tableSelectOSX.a BETWEEN 'apra' AND 'aprt'=======
Error in query:  near "case": syntax error

Request: Support UUID datatypes

It is generally considered good practice to use UUIDs for exposed table keys to avoid exposing the total number of records in a table or allow a malicious party to enumerate over potentially valid items in the DB. They are also very useful for many different scenarios.

Queries

Using PostgreSQL as an example, UUIDs are specified using the following notation: 'b07ae461-854e-41bc-aa40-a75900c4be59'::uuid. Currently this requires a raw query (or partially raw query) to select. I propose that Kuery supports using UUID structs or NSUUID class instances as input types for .Select().

This would require updating the functions Utils.packType() and Utils.packType(_, queryBuilder:) with a new case like the following:

        case let value as UUID:
            return "'\(value.uuidString))'::uuid"

The above code is valid for PostgreSQL, but I would assume that it needs to be overloaded by DB-specific code in each implementation.

Results

Currently Kuery returns UUIDs as a Data()-type with 16 bytes. It would be helpful to be able to cast the result as? UUID or as? NSUUID.

As I understand Kuery this is very specific to each DB driver. For PostgreSQL, the OID of the uuid datatype needs to be added to PostgreSQLType.swift and PostgreSQLResultFetcher.convert(_ , row: , column:) needs to add a new .case for this datatype. This function needs to read the raw bytes into a UUID or NSUUID. Example:

return data.withUnsafeBytes { (bytes: UnsafePointer<UInt8>) -> NSUUID in
    return NSUUID(uuidBytes: bytes)
}

Considerations

It should be considered wether to use NSUUID or UUID as the input/result object. This is way beyond my competence. The only caveat I've seen is that UUIDs will need to be initialized with a tuple of 16 UInt8s, which is a pain. NSUUID can be initialized with a UnsafePointer<UInt8> which seems a little more straightforward.

Recommend Projects

  • React photo React

    A declarative, efficient, and flexible JavaScript library for building user interfaces.

  • Vue.js photo Vue.js

    🖖 Vue.js is a progressive, incrementally-adoptable JavaScript framework for building UI on the web.

  • Typescript photo Typescript

    TypeScript is a superset of JavaScript that compiles to clean JavaScript output.

  • TensorFlow photo TensorFlow

    An Open Source Machine Learning Framework for Everyone

  • Django photo Django

    The Web framework for perfectionists with deadlines.

  • D3 photo D3

    Bring data to life with SVG, Canvas and HTML. 📊📈🎉

Recommend Topics

  • javascript

    JavaScript (JS) is a lightweight interpreted programming language with first-class functions.

  • web

    Some thing interesting about web. New door for the world.

  • server

    A server is a program made to process requests and deliver data to clients.

  • Machine learning

    Machine learning is a way of modeling and interpreting data that allows a piece of software to respond intelligently.

  • Game

    Some thing interesting about game, make everyone happy.

Recommend Org

  • Facebook photo Facebook

    We are working to build community through open source technology. NB: members must have two-factor auth.

  • Microsoft photo Microsoft

    Open source projects and samples from Microsoft.

  • Google photo Google

    Google ❤️ Open Source for everyone.

  • D3 photo D3

    Data-Driven Documents codes.