~evanj/cms

ref: 41bddf091e571b359b94d1f4287ccb471fb29d03 cms/internal/s/db/db.go -rw-r--r-- 9.5 KiB
41bddf09Evan M Jones WIP(perPage/after): Testing to see if this is viable. 4 months ago
                                                                                
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
package db

import (
	"database/sql"
	"log"
	"strconv"
	"strings"

	"git.sr.ht/~evanj/cms/internal/m/valuetype"
	"git.sr.ht/~evanj/security"
	_ "github.com/go-sql-driver/mysql"
)

const (
	// Default pagination amount. For use in LIMIT/OFFSET.
	maxPerPage = 25

	maxUint = ^uint(0)
	maxInt  = int(maxUint >> 1)
)

var (
	// Max before value to be used for pagination when user has specified zero
	// value.
	maxBefore = strconv.Itoa(maxInt)
	zero      int
)

func bfmt(before int) int {
	if before == zero {
		return maxInt
	}
	return before
}

func afmt(after int) int {
	return after
}

func pfmt(page int) int {
	if page > maxPerPage || page < 1 {
		return maxPerPage
	}
	return page
}

type DB struct {
	*sql.DB
	log *log.Logger
	sec securer
}

// securer provides us two things:
// 	 1. Creating user tokens (for use in cookie/other).
// 	 2. Creating salt+hashes for passwords.
type securer interface {
	TokenCreate(val security.TokenMap) (string, error)
	TokenFrom(tokenString string) (security.TokenMap, error)
	HashCreate(salt, pass string) (string, error)
	HashCompare(salt, pass, hash string) error
}

// New, does as one might expect, given a logger, type of database, database
// connection string, and securer interface, opens a pool'd connection to a
// mysql database and pings. If ping fails we return error and nil *DB.
func New(log *log.Logger, typ, creds string, sec securer) (*DB, error) {
	conn, err := sql.Open(typ, creds)
	if err != nil {
		return nil, err
	}

	if err := conn.Ping(); err != nil {
		return nil, err
	}

	// TODO: Best numbers?
	conn.SetMaxIdleConns(10)
	conn.SetMaxOpenConns(100)

	db := &DB{
		conn,
		log,
		sec,
	}

	return db, nil
}

// NewWithConn creates a *DB type and pings the MySQL server. If ping fails we
// return error.
func NewWithConn(log *log.Logger, sec securer, conn *sql.DB) (*DB, error) {
	if err := conn.Ping(); err != nil {
		return nil, err
	}

	// TODO: Best numbers?
	conn.SetMaxIdleConns(10)
	conn.SetMaxOpenConns(100)

	db := &DB{
		conn,
		log,
		sec,
	}

	return db, nil
}

// createTables does our "migration" -migration in quotes as we just dummy
// attempt to create tables on every server startup and ignore "table already
// exists" errors.
func (db *DB) createTables() []error {
	var errors []error
	var err error

	var _ interface{}

	// user
	_, err = db.Exec(`
		CREATE TABLE cms_user (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			NAME varchar(256) UNIQUE NOT NULL,
			HASH varchar(256) NOT NULL
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// space
	_, err = db.Exec(`
		CREATE TABLE cms_space (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			NAME varchar(256) NOT NULL,
			DESCRIPTION varchar(256) NOT NULL
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// user to space
	_, err = db.Exec(`
		CREATE TABLE cms_user_to_space (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			USER_ID INTEGER NOT NULL,
			SPACE_ID INTEGER NOT NULL,
			FOREIGN KEY(USER_ID) REFERENCES cms_user(ID),
			FOREIGN KEY(SPACE_ID) REFERENCES cms_space(ID) ON DELETE CASCADE
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// contenttype
	_, err = db.Exec(`
		CREATE TABLE cms_contenttype (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			NAME varchar(256) NOT NULL,
			SPACE_ID INTEGER NOT NULL,
			CONSTRAINT FG FOREIGN KEY(SPACE_ID) REFERENCES cms_space(ID) ON DELETE CASCADE,
			CONSTRAINT UNIQUEPERCONN UNIQUE(SPACE_ID, NAME)
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// valuetype
	// This will never be created by users.
	_, err = db.Exec(`
		CREATE TABLE cms_valuetype (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			VALUE varchar(256) UNIQUE NOT NULL
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// contenttype to valuetype
	// TODO: Make name + contenttype_id unique.
	_, err = db.Exec(`
		CREATE TABLE cms_contenttype_to_valuetype (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			NAME varchar(256) NOT NULL,
			CONTENTTYPE_ID INTEGER NOT NULL,
			VALUETYPE_ID INTEGER NOT NULL,
			FOREIGN KEY(CONTENTTYPE_ID) REFERENCES cms_contenttype(ID) ON DELETE CASCADE,
			FOREIGN KEY(VALUETYPE_ID) REFERENCES cms_valuetype(ID)
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// content
	_, err = db.Exec(`
		CREATE TABLE cms_content (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			CONTENTTYPE_ID INTEGER NOT NULL,
			FOREIGN KEY(CONTENTTYPE_ID) REFERENCES cms_contenttype(ID) ON DELETE CASCADE
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// content_to_value
	_, err = db.Exec(`
		CREATE TABLE cms_value (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			CONTENT_ID INTEGER NOT NULL,
			CONTENTTYPE_TO_VALUETYPE_ID INTEGER NOT NULL, 
			VALUE_ID INTEGER NOT NULL, -- Should be a foreign key but impossible to make it for two+ tables.
			FOREIGN KEY(CONTENT_ID) REFERENCES cms_content(ID) ON DELETE CASCADE,
			FOREIGN KEY(CONTENTTYPE_TO_VALUETYPE_ID) REFERENCES cms_contenttype_to_valuetype(ID) ON DELETE CASCADE
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// value StringSmall, File
	_, err = db.Exec(`
		CREATE TABLE cms_value_string_small ( 
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			VALUE VARCHAR(256) NOT NULL
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// value StringBig, InputHTML, InputMarkdown
	_, err = db.Exec(`
		CREATE TABLE cms_value_string_big (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			VALUE TEXT NOT NULL
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// value Date
	_, err = db.Exec(`
		CREATE TABLE cms_value_date (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			VALUE DATE NOT NULL
		);
	`)

	// TODO: Reconsider these ON DELETE CASCADES after this point.

	// value Reference
	_, err = db.Exec(`
		CREATE TABLE cms_value_reference (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			VALUE INTEGER NOT NULL,
			FOREIGN KEY(VALUE) REFERENCES cms_content(ID) ON DELETE CASCADE
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// value ReferenceList
	_, err = db.Exec(`
		CREATE TABLE cms_value_reference_list (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// augment to ReferenceList
	_, err = db.Exec(`
		CREATE TABLE cms_value_reference_list_values (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			VALUE_ID INTEGER NOT NULL,
			CONTENT_ID INTEGER NOT NULL,
			FOREIGN KEY(VALUE_ID) REFERENCES cms_value_reference_list(ID) ON DELETE CASCADE,
			FOREIGN KEY(CONTENT_ID) REFERENCES cms_content(ID) ON DELETE CASCADE
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// Webhook
	_, err = db.Exec(`
		CREATE TABLE cms_hooks (
			ID INTEGER PRIMARY KEY AUTO_INCREMENT,
			URL varchar(256) NOT NULL,
			SPACE_ID INTEGER NOT NULL,
			FOREIGN KEY(SPACE_ID) REFERENCES cms_space(ID) ON DELETE CASCADE,
			CONSTRAINT UNIQUEPERCONN UNIQUE(SPACE_ID, URL)
		);
	`)
	if err != nil {
		errors = append(errors, err)
	}

	// Only valuetypes cms supports.
	_, err = db.Exec(`INSERT INTO cms_valuetype (VALUE) values (?);`, valuetype.StringSmall)
	if err != nil {
		errors = append(errors, err)
	}

	_, err = db.Exec(`INSERT INTO cms_valuetype (VALUE) values (?);`, valuetype.StringBig)
	if err != nil {
		errors = append(errors, err)
	}

	_, err = db.Exec(`INSERT INTO cms_valuetype (VALUE) values (?);`, valuetype.InputHTML)
	if err != nil {
		errors = append(errors, err)
	}

	_, err = db.Exec(`INSERT INTO cms_valuetype (VALUE) values (?);`, valuetype.InputMarkdown)
	if err != nil {
		errors = append(errors, err)
	}

	_, err = db.Exec(`INSERT INTO cms_valuetype (VALUE) values (?);`, valuetype.File)
	if err != nil {
		errors = append(errors, err)
	}

	_, err = db.Exec(`INSERT INTO cms_valuetype (VALUE) values (?);`, valuetype.Date)
	if err != nil {
		errors = append(errors, err)
	}

	_, err = db.Exec(`INSERT INTO cms_valuetype (VALUE) values (?);`, valuetype.Reference)
	if err != nil {
		errors = append(errors, err)
	}

	_, err = db.Exec(`INSERT INTO cms_valuetype (VALUE) values (?);`, valuetype.ReferenceList)
	if err != nil {
		errors = append(errors, err)
	}

	return errors
}

// Ensure we have the tables we require. If we receive an error other
// than "table already exists" and also "duplicate entry" for built in data
// types that error will be returned.
// Mainly, we are runnin CREATE TABLE and some INSERT INTO of predefined
// value types.
func (db *DB) EnsureSetup() error {
	for _, err := range db.createTables() {
		errmsg := err.Error()

		if err != nil && strings.Contains(errmsg, "Table ") && strings.Contains(errmsg, "already exists") {
			continue
		}

		if err != nil && strings.Contains(errmsg, "Duplicate entry ") && strings.Contains(errmsg, "VALUE") {
			continue
		}

		return err
	}

	return nil
}

// FileExists makes sure SOME space and content owns the file. I.E. deleted
// spaces can't server files.
func (db *DB) FileExists(URL string) (bool, error) {
	q := `
		SELECT cms_space.ID FROM cms_value_string_small 
		JOIN cms_value ON cms_value.VALUE_ID = cms_value_string_small.ID
		JOIN cms_contenttype_to_valuetype ON cms_value.CONTENTTYPE_TO_VALUETYPE_ID = cms_contenttype_to_valuetype.ID 
		JOIN cms_valuetype ON cms_contenttype_to_valuetype.VALUETYPE_ID = cms_valuetype.ID
		JOIN cms_contenttype ON cms_contenttype_to_valuetype.CONTENTTYPE_ID = cms_contenttype.ID
		JOIN cms_content ON cms_content.CONTENTTYPE_ID = cms_contenttype.ID
		JOIN cms_space ON cms_contenttype.SPACE_ID = cms_space.ID
		WHERE cms_valuetype.VALUE = ? AND cms_value_string_small.VALUE = ?
	`

	var spaceID string
	if err := db.QueryRow(q, valuetype.File, URL).Scan(&spaceID); err != nil {
		db.log.Println("FileExists", err)
		return false, err
	}

	return true, nil
}