aboutsummaryrefslogtreecommitdiff
path: root/src/main/kotlin/moe/nea/ledger/database/DBSchema.kt
blob: 492f261bb8390755e1d6b7523818b7f8b9d9e4b1 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
package moe.nea.ledger.database

import moe.nea.ledger.UUIDUtil
import java.sql.Connection
import java.sql.PreparedStatement
import java.sql.ResultSet
import java.time.Instant
import java.util.UUID

interface DBSchema {
	val tables: List<Table>
}

interface DBType<T> {
	val dbType: String

	fun get(result: ResultSet, index: Int): T
	fun set(stmt: PreparedStatement, index: Int, value: T)
	fun getName(): String = javaClass.simpleName
	fun <R> mapped(
		from: (R) -> T,
		to: (T) -> R,
	): DBType<R> {
		return object : DBType<R> {
			override fun getName(): String {
				return "Mapped(${this@DBType.getName()})"
			}

			override val dbType: String
				get() = this@DBType.dbType

			override fun get(result: ResultSet, index: Int): R {
				return to(this@DBType.get(result, index))
			}

			override fun set(stmt: PreparedStatement, index: Int, value: R) {
				this@DBType.set(stmt, index, from(value))
			}
		}
	}
}

object DBUuid : DBType<UUID> {
	override val dbType: String
		get() = "TEXT"

	override fun get(result: ResultSet, index: Int): UUID {
		return UUIDUtil.parseDashlessUuid(result.getString(index))
	}

	override fun set(stmt: PreparedStatement, index: Int, value: UUID) {
		stmt.setString(index, value.toString())
	}
}

object DBUlid : DBType<UUIDUtil.ULIDWrapper> {
	override val dbType: String
		get() = "TEXT"

	override fun get(result: ResultSet, index: Int): UUIDUtil.ULIDWrapper {
		val text = result.getString(index)
		return UUIDUtil.ULIDWrapper(text)
	}

	override fun set(stmt: PreparedStatement, index: Int, value: UUIDUtil.ULIDWrapper) {
		stmt.setString(index, value.wrapped)
	}
}

object DBString : DBType<String> {
	override val dbType: String
		get() = "TEXT"

	override fun get(result: ResultSet, index: Int): String {
		return result.getString(index)
	}

	override fun set(stmt: PreparedStatement, index: Int, value: String) {
		stmt.setString(index, value)
	}
}

class DBEnum<T : Enum<T>>(
	val type: Class<T>,
) : DBType<T> {
	companion object {
		inline operator fun <reified T : Enum<T>> invoke(): DBEnum<T> {
			return DBEnum(T::class.java)
		}
	}

	override val dbType: String
		get() = "TEXT"

	override fun getName(): String {
		return "DBEnum(${type.simpleName})"
	}

	override fun set(stmt: PreparedStatement, index: Int, value: T) {
		stmt.setString(index, value.name)
	}

	override fun get(result: ResultSet, index: Int): T {
		val name = result.getString(index)
		return java.lang.Enum.valueOf(type, name)
	}
}

object DBDouble : DBType<Double> {
	override val dbType: String
		get() = "DOUBLE"

	override fun get(result: ResultSet, index: Int): Double {
		return result.getDouble(index)
	}

	override fun set(stmt: PreparedStatement, index: Int, value: Double) {
		stmt.setDouble(index, value)
	}
}

object DBInt : DBType<Long> {
	override val dbType: String
		get() = "INTEGER"

	override fun get(result: ResultSet, index: Int): Long {
		return result.getLong(index)
	}

	override fun set(stmt: PreparedStatement, index: Int, value: Long) {
		stmt.setLong(index, value)
	}
}

object DBInstant : DBType<Instant> {
	override val dbType: String
		get() = "INTEGER"

	override fun set(stmt: PreparedStatement, index: Int, value: Instant) {
		stmt.setLong(index, value.toEpochMilli())
	}

	override fun get(result: ResultSet, index: Int): Instant {
		return Instant.ofEpochMilli(result.getLong(index))
	}
}

class Column<T> @Deprecated("Use Table.column instead") constructor(
	val table: Table,
	val name: String,
	val type: DBType<T>
) {
	val sqlName get() = "`$name`"
	val qualifiedSqlName get() = table.sqlName + "." + sqlName
}

interface Constraint {
	val affectedColumns: Collection<Column<*>>
	fun asSQL(): String
}

class UniqueConstraint(val columns: List<Column<*>>) : Constraint {
	init {
		require(columns.isNotEmpty())
	}

	override val affectedColumns: Collection<Column<*>>
		get() = columns

	override fun asSQL(): String {
		return "UNIQUE (${columns.joinToString() { it.sqlName }})"
	}
}

abstract class Table(val name: String) {
	val sqlName get() = "`$name`"
	protected val _mutable_columns: MutableList<Column<*>> = mutableListOf()
	protected val _mutable_constraints: MutableList<Constraint> = mutableListOf()
	val columns: List<Column<*>> get() = _mutable_columns
	val constraints get() = _mutable_constraints
	protected fun unique(vararg columns: Column<*>) {
		_mutable_constraints.add(UniqueConstraint(columns.toList()))
	}

	protected fun <T> column(name: String, type: DBType<T>): Column<T> {
		@Suppress("DEPRECATION") val column = Column(this, name, type)
		_mutable_columns.add(column)
		return column
	}

	fun debugSchema() {
		val nameWidth = columns.maxOf { it.name.length }
		val typeWidth = columns.maxOf { it.type.getName().length }
		val totalWidth = maxOf(2 + nameWidth + 3 + typeWidth + 2, name.length + 4)
		val adjustedTypeWidth = totalWidth - nameWidth - 2 - 3 - 2

		var string = "\n"
		string += ("+" + "-".repeat(totalWidth - 2) + "+\n")
		string += ("| $name${" ".repeat(totalWidth - 4 - name.length)} |\n")
		string += ("+" + "-".repeat(totalWidth - 2) + "+\n")
		for (column in columns) {
			string += ("| ${column.name}${" ".repeat(nameWidth - column.name.length)} |")
			string += (" ${column.type.getName()}" +
					"${" ".repeat(adjustedTypeWidth - column.type.getName().length)} |\n")
		}
		string += ("+" + "-".repeat(totalWidth - 2) + "+")
		println(string)
	}

	fun createIfNotExists(
		connection: Connection,
		filteredColumns: List<Column<*>> = columns
	) {
		val properties = mutableListOf<String>()
		for (column in filteredColumns) {
			properties.add("${column.sqlName} ${column.type.dbType}")
		}
		val columnSet = filteredColumns.toSet()
		for (constraint in constraints) {
			if (columnSet.containsAll(constraint.affectedColumns)) {
				properties.add(constraint.asSQL())
			}
		}
		connection.prepareAndLog("CREATE TABLE IF NOT EXISTS $sqlName (" + properties.joinToString() + ")")
			.execute()
	}

	fun alterTableAddColumns(
		connection: Connection,
		newColumns: List<Column<*>>
	) {
		for (column in newColumns) {
			connection.prepareAndLog("ALTER TABLE $sqlName ADD ${column.sqlName} ${column.type.dbType}")
				.execute()
		}
		for (constraint in constraints) {
			// TODO: automatically add constraints, maybe (or maybe move constraints into the upgrade schema)
		}
	}

	enum class OnConflict {
		FAIL,
		IGNORE,
		REPLACE,
		;

		fun asSql(): String {
			return name
		}
	}

	fun insert(connection: Connection, onConflict: OnConflict = OnConflict.FAIL, block: (InsertStatement) -> Unit) {
		val insert = InsertStatement(HashMap())
		block(insert)
		require(insert.properties.keys == columns.toSet())
		val columnNames = columns.joinToString { it.sqlName }
		val valueNames = columns.joinToString { "?" }
		val statement =
			connection.prepareAndLog("INSERT OR ${onConflict.asSql()} INTO $sqlName ($columnNames) VALUES ($valueNames)")
		for ((index, column) in columns.withIndex()) {
			(column as Column<Any>).type.set(statement, index + 1, insert.properties[column]!!)
		}
		statement.execute()
	}

	fun from(connection: Connection): Query {
		return Query(connection, mutableListOf(), this)
	}

	fun selectAll(connection: Connection): Query {
		return Query(connection, columns.toMutableList(), this)
	}
}

class InsertStatement(val properties: MutableMap<Column<*>, Any>) {
	operator fun <T : Any> set(key: Column<T>, value: T) {
		properties[key] = value
	}
}

fun Connection.prepareAndLog(statement: String): PreparedStatement {
	println("Preparing to execute $statement")
	return prepareStatement(statement)
}

interface SQLQueryComponent {
	fun asSql(): String

	/**
	 * @return the next writable index (should equal to the amount of `?` in [asSql] + [startIndex])
	 */
	fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int

	companion object {
		fun standalone(sql: String): SQLQueryComponent {
			return object : SQLQueryComponent {
				override fun asSql(): String {
					return sql
				}

				override fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int {
					return startIndex
				}
			}
		}
	}
}

interface BooleanExpression : SQLQueryComponent

data class ORExpression(
	val elements: List<BooleanExpression>
) : BooleanExpression {
	init {
		require(elements.isNotEmpty())
	}

	override fun asSql(): String {
		return (elements + SQLQueryComponent.standalone("FALSE")).joinToString(" OR ", "(", ")") { it.asSql() }
	}

	override fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int {
		var index = startIndex
		for (element in elements) {
			index = element.appendToStatement(stmt, index)
		}
		return index
	}
}


data class ANDExpression(
	val elements: List<BooleanExpression>
) : BooleanExpression {
	init {
		require(elements.isNotEmpty())
	}

	override fun asSql(): String {
		return (elements + SQLQueryComponent.standalone("TRUE")).joinToString(" AND ", "(", ")") { it.asSql() }
	}

	override fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int {
		var index = startIndex
		for (element in elements) {
			index = element.appendToStatement(stmt, index)
		}
		return index
	}
}

class ClauseBuilder {
	fun <T> column(column: Column<T>): Operand<T> = Operand.ColumnOperand(column)
	fun string(string: String): Operand.StringOperand = Operand.StringOperand(string)
	infix fun Operand<*>.eq(operand: Operand<*>) = Clause.EqualsClause(this, operand)
	infix fun Operand<*>.like(op: Operand.StringOperand) = Clause.LikeClause(this, op)
	infix fun Operand<*>.like(op: String) = Clause.LikeClause(this, string(op))
}

interface Clause : BooleanExpression {
	companion object {
		operator fun invoke(builder: ClauseBuilder.() -> Clause): Clause {
			return builder(ClauseBuilder())
		}
	}

	data class EqualsClause(val left: Operand<*>, val right: Operand<*>) : Clause { // TODO: typecheck this somehow
		override fun asSql(): String {
			return left.asSql() + " = " + right.asSql()
		}

		override fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int {
			var index = startIndex
			index = left.appendToStatement(stmt, index)
			index = right.appendToStatement(stmt, index)
			return index
		}
	}

	data class LikeClause<T>(val left: Operand<T>, val right: Operand.StringOperand) : Clause {
		//TODO: check type safety with this one
		override fun asSql(): String {
			return "(" + left.asSql() + " LIKE " + right.asSql() + ")"
		}

		override fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int {
			var index = startIndex
			index = left.appendToStatement(stmt, index)
			index = right.appendToStatement(stmt, index)
			return index
		}
	}
}

interface Operand<T> : SQLQueryComponent {
	data class ColumnOperand<T>(val column: Column<T>) : Operand<T> {
		override fun asSql(): String {
			return column.qualifiedSqlName
		}

		override fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int {
			return startIndex
		}
	}

	data class StringOperand(val value: String) : Operand<String> {
		override fun asSql(): String {
			return "?"
		}

		override fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int {
			stmt.setString(startIndex, value)
			return 1 + startIndex
		}
	}
}

data class Join(
	val table: Table,
//TODO: aliased columns	val tableAlias: String,
	val filter: Clause,
) : SQLQueryComponent {
	//	JOIN ItemEntry on LogEntry.transactionId = ItemEntry.transactionId
	override fun asSql(): String {
		return "JOIN ${table.sqlName} ON ${filter.asSql()}"
	}

	override fun appendToStatement(stmt: PreparedStatement, startIndex: Int): Int {
		return filter.appendToStatement(stmt, startIndex)
	}
}

fun List<SQLQueryComponent>.concatToFilledPreparedStatement(connection: Connection): PreparedStatement {
	var query = ""
	for (element in this) {
		if (query.isNotEmpty()) {
			query += " "
		}
		query += element.asSql()
	}
	val statement = connection.prepareAndLog(query)
	var index = 1
	for (element in this) {
		val nextIndex = element.appendToStatement(statement, index)
		if (nextIndex < index) error("$element went back in time")
		index = nextIndex
	}
	return statement
}

class Query(
	val connection: Connection,
	val selectedColumns: MutableList<Column<*>>,
	var table: Table,
	var limit: UInt? = null,
	var skip: UInt? = null,
	val joins: MutableList<Join> = mutableListOf(),
	val conditions: MutableList<BooleanExpression> = mutableListOf(),
//	var order: OrderClause?= null,
) : Iterable<ResultRow> {
	fun join(table: Table, on: Clause): Query {
		joins.add(Join(table, on))
		return this
	}

	fun where(binOp: BooleanExpression): Query {
		conditions.add(binOp)
		return this
	}

	fun select(vararg columns: Column<*>): Query {
		selectedColumns.addAll(columns)
		return this
	}

	fun skip(skip: UInt): Query {
		require(limit != null)
		this.skip = skip
		return this
	}

	fun limit(limit: UInt): Query {
		this.limit = limit
		return this
	}

	override fun iterator(): Iterator<ResultRow> {
		val columnSelections = selectedColumns.joinToString { it.qualifiedSqlName }
		val elements = mutableListOf(
			SQLQueryComponent.standalone("SELECT $columnSelections FROM ${table.sqlName}"),
		)
		elements.addAll(joins)
		if (conditions.any()) {
			elements.add(SQLQueryComponent.standalone("WHERE"))
			elements.add(ANDExpression(conditions))
		}
		if (limit != null) {
			elements.add(SQLQueryComponent.standalone("LIMIT $limit"))
			if (skip != null) {
				elements.add(SQLQueryComponent.standalone("OFFSET $skip"))
			}
		}
		val prepared = elements.concatToFilledPreparedStatement(connection)
		val results = prepared.executeQuery()
		return object : Iterator<ResultRow> {
			var hasAdvanced = false
			var hasEnded = false
			override fun hasNext(): Boolean {
				if (hasEnded) return false
				if (hasAdvanced) return true
				if (results.next()) {
					hasAdvanced = true
					return true
				} else {
					results.close() // TODO: somehow enforce closing this
					hasEnded = true
					return false
				}
			}

			override fun next(): ResultRow {
				if (!hasNext()) {
					throw NoSuchElementException()
				}
				hasAdvanced = false
				return ResultRow(selectedColumns.withIndex().associate {
					it.value to it.value.type.get(results, it.index + 1)
				})
			}

		}
	}
}

class ResultRow(val columnValues: Map<Column<*>, *>) {
	operator fun <T> get(column: Column<T>): T {
		val value = columnValues[column]
			?: error("Invalid column ${column.name}. Only ${columnValues.keys.joinToString { it.name }} are available.")
		return value as T
	}
}