File: strict_typing.sql

package info (click to toggle)
sqliteodbc 0.9996-1
  • links: PTS, VCS
  • area: main
  • in suites: buster
  • size: 4,640 kB
  • sloc: ansic: 58,334; sh: 12,515; makefile: 952; sql: 313
file content (396 lines) | stat: -rw-r--r-- 11,474 bytes parent folder | download | duplicates (17)
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
-- Example for SQLite + TinyCC taken from the book
-- "The Definitive Guide to SQLite" by Mike Owen, Chapter 7, p. 267-278

.echo on
-- Loading sqlite+tcc.dll ...
.load 'sqlite+tcc.dll'

-- Compiling code (SQL not shown) ...
.echo off
select tcc_compile('

#include <sqlite3.h>

/* Installs type validation triggers on column. It first looks the column''s
** declared type in the schema and attempts find the matching validation
** function (validate_xxx()). If on exists, it creates INSERT/UPDATE triggers
** to call validation function.
*/
void add_strict_type_check_udf(sqlite3_context* ctx, int nargs,
    sqlite3_value **values);

/* Helper function. Installs validation trigger on column */
int install_type_trigger(sqlite3 *db, sqlite3_context *ctx, 
    char *table, char *column);

/* Drops validation triggers on column */
void drop_strict_type_check_udf(sqlite3_context *ctx, int nargs,
    sqlite3_value **values);

/* Helper function. Drops validation trigger on column */
int uninstall_type_trigger(sqlite3 *db, sqlite3_context *ctx,
    char *table, char *column);

/* User-defined integer validation function. Use for integers, longs, etc. */
void validate_int_udf(sqlite3_context *ctx, int nargs, sqlite3_value **values);

/* User-defined float validation function. Use for floats, doubles, etc. */
void validate_double_udf(sqlite3_context *ctx, int nargs,
    sqlite3_value **values);

/* User-defined column type function. Given a table name and column name,
** returns a column''s declared type. 
*/
void column_type_udf(sqlite3_context *ctx, int nargs, sqlite3_value **values);

/* C Function: Lookup column''s declared type in sqlite_master. */
char* column_type(sqlite3 *db, char *table, char *column);

/* Initializer for this module */
void init(
  sqlite3 *db
){
  sqlite3_create_function(db, "add_strict_type_check", 2, SQLITE_UTF8, db,
      add_strict_type_check_udf, 0, 0);
  sqlite3_create_function(db, "drop_strict_type_check", 2, SQLITE_UTF8, db,
      drop_strict_type_check_udf, 0, 0);
  sqlite3_create_function(db, "column_type", 2, SQLITE_UTF8, db,
      column_type_udf, 0, 0);
  sqlite3_create_function(db, "validate_int", 1, SQLITE_UTF8, db,
      validate_int_udf, 0, 0);
  sqlite3_create_function(db, "validate_long", 1, SQLITE_UTF8, db,
      validate_int_udf, 0, 0);
  sqlite3_create_function(db, "validate_double", 1, SQLITE_UTF8, db,
      validate_double_udf, 0, 0);
  sqlite3_create_function(db, "validate_float", 1, SQLITE_UTF8, db,
      validate_double_udf, 0, 0);
}

void add_strict_type_check_udf(
  sqlite3_context *ctx,
  int nargs, 
  sqlite3_value **values
){
  sqlite3 *db;
  sqlite3_stmt *stmt;
  int rc;
  char *table, *column, *sql, *tmp;
  db = (sqlite3*) sqlite3_user_data(ctx);
  table = (char*) sqlite3_value_text(values[0]);
  column = (char*) sqlite3_value_text(values[1]);
  if( strncmp(column, "*", 1) == 0 ){
    /* Install on all columns */
    sql = "pragma table_info(%s)";
    tmp = sqlite3_mprintf(sql, table);
    rc = sqlite3_prepare(db, tmp, -1, &stmt, 0);
    sqlite3_free(tmp);
    if( rc != SQLITE_OK ){
      sqlite3_result_error(ctx, sqlite3_errmsg(db), -1);
      return;
    }
    rc = sqlite3_step(stmt);
    while( rc == SQLITE_ROW ){
      /* If not primary key */
      if( sqlite3_column_int(stmt, 5) != 1 ){
        column = (char*) sqlite3_column_text(stmt, 1); 
        install_type_trigger(db, ctx, table, column);
      }
      rc = sqlite3_step(stmt);
    }
    sqlite3_finalize(stmt);
  }else{
    /* Just installing on a single column */
    if( install_type_trigger(db, ctx, table, column) != 0 ){
      return;
    }
  }
  sqlite3_result_int(ctx, 0);
}

int install_type_trigger(
  sqlite3 *db,
  sqlite3_context *ctx, 
  char *table,
  char *column
){
  int rc;
  char buf[256];
  char *err, *sql, *type, *tmp;
  type = column_type(db, table, column);
  if( type == 0 ){
    sqlite3_result_error(ctx, "column has no declared type", -1);
    sqlite3_free(type);
    return 1;
  }
  /* Check to see if corresponding validation function exists */
  sql = "select validate_%s(null)";
  tmp = sqlite3_mprintf(sql, type);
  rc = sqlite3_exec(db, tmp, 0, 0, &err);
  sqlite3_free(tmp);
  if( rc != SQLITE_OK && err != 0 ){
    sqlite3_result_error(ctx, "no validator exists for column type", -1);
    sqlite3_free(type);
    sqlite3_free(err);
    return 1;
  }
  /* Create INSERT trigger */
  sql = "CREATE TRIGGER %s_insert_%s_typecheck_tr \n"
        "BEFORE INSERT ON %s \n"
        "BEGIN \n"
        "   SELECT CASE \n"
        "     WHEN(SELECT validate_%s(new.%s) != 1) \n"
        "     THEN RAISE(ABORT, ''invalid %s value for %s.%s'') \n"
        "   END; \n"
        "END;";
  tmp = sqlite3_mprintf(sql, table, column, table, type, 
            column, type, table, column);    
  rc = sqlite3_exec(db, tmp, 0, 0, &err);
  sqlite3_free(tmp);
  if( rc != SQLITE_OK && err != 0 ){
    strncpy(&buf[0], err, 255);
    buf[255] = ''\0'';
    sqlite3_result_error(ctx, &buf[0], -1);
    sqlite3_free(type);
    return 1;
  }
  /* Create UPDATE trigger */
  sql = "CREATE TRIGGER %s_update_%s_typecheck_tr \n"
        "BEFORE UPDATE OF %s ON %s \n"
        "FOR EACH ROW BEGIN \n"
        "  SELECT CASE \n"
        "    WHEN(SELECT validate_%s(new.%s) != 1) \n"
        "    THEN RAISE(ABORT, ''invalid %s value for %s.%s'') \n"
        "  END; \n"
        "END;";
  tmp = sqlite3_mprintf(sql, table, column, column, table, 
            type, column, type, table, column);
  rc = sqlite3_exec(db, tmp, 0, 0, &err);
  sqlite3_free(tmp);
  sqlite3_free(type);
  if( rc != SQLITE_OK && err != 0 ) {
    strncpy(&buf[0], err, 255);
    buf[255] = ''\0'';
    sqlite3_result_error(ctx, &buf[0], -1);
    sqlite3_free(err);
    return 1;
  }
  return 0;
}

void drop_strict_type_check_udf(
  sqlite3_context *ctx,
  int nargs,
  sqlite3_value **values
){
  sqlite3 *db;
  sqlite3_stmt *stmt;
  int rc;
  char *table, *column, *sql, *tmp;
  db = (sqlite3*) sqlite3_user_data(ctx);
  table = (char*) sqlite3_value_text(values[0]);
  column = (char*) sqlite3_value_text(values[1]);
  if( strncmp(column,"*",1) == 0 ){
    /* Install on all columns */
    sql = "pragma table_info(%s)";
    tmp = sqlite3_mprintf(sql, table);
    rc = sqlite3_prepare(db, tmp, -1, &stmt, 0);
    sqlite3_free(tmp);
    if( rc != SQLITE_OK ){
      sqlite3_result_error(ctx, sqlite3_errmsg(db), -1);
      return;
    }
    rc = sqlite3_step(stmt);
    while( rc == SQLITE_ROW ){
      /* If not primary key */
      if( sqlite3_column_int(stmt, 5) != 1 ){
        column = (char*) sqlite3_column_text(stmt, 1); 
        uninstall_type_trigger(db, ctx, table, column);
      }
      rc = sqlite3_step(stmt);
    }
    sqlite3_finalize(stmt);
  }else{
    /* Just installing on a single column */
    if( uninstall_type_trigger(db, ctx, table, column) != 0 ){
      return;
    }
  }
  sqlite3_result_int(ctx, 0);
}

/* Helper function. Drops validation trigger on column */
int uninstall_type_trigger(
  sqlite3 *db,
  sqlite3_context *ctx,
  char *table,
  char *column
){
  int rc;
  char buf[256];
  char *tmp, *err, *sql;
  /* Drop INSERT trigger */
  sql = "DROP TRIGGER %s_insert_%s_typecheck_tr";
  tmp = sqlite3_mprintf(sql, table, column);    
  rc = sqlite3_exec(db, tmp, 0, 0, &err);
  sqlite3_free(tmp);
  if( rc != SQLITE_OK && err != 0 ){
    strncpy(&buf[0], err, 255);
    buf[255] = ''\0'';
    sqlite3_result_error(ctx, &buf[0], -1);
    return 1;
  }
  /* Drop UPDATE trigger */
  sql = "DROP TRIGGER %s_update_%s_typecheck_tr";
  tmp = sqlite3_mprintf(sql, table, column);    
  rc = sqlite3_exec(db, tmp, 0, 0, &err);
  sqlite3_free(tmp);
  if( rc != SQLITE_OK && err != 0 ){
    strncpy(&buf[0], err, 255);
    buf[255] = ''\0'';
    sqlite3_result_error(ctx, &buf[0], -1);
    return 1;
  }
  return 0;
}

void validate_int_udf(
  sqlite3_context *ctx,
  int nargs,
  sqlite3_value **values
){
  sqlite3 *db;
  char *value;
  char *tmp;
  db = (sqlite3*) sqlite3_user_data(ctx);
  value = (char*) sqlite3_value_text(values[0]);
  /* Assuming NULL values for type checked columns not allowed */
  if( value == 0 ){
    sqlite3_result_int(ctx, 0);
    return;
  }
  /* Validate type: */
  tmp = 0;
  strtol(value, &tmp, 0);
  if( *tmp != ''\0'' ){
    /* Value does not conform to type */
    sqlite3_result_int(ctx, 0);
    return;
  }
  /* If we got this far value is valid. */
  sqlite3_result_int(ctx, 1);
}

void validate_double_udf(
  sqlite3_context* ctx,
  int nargs,
  sqlite3_value** values
){
  sqlite3 *db;
  char *value;
  char *tmp;
  db = (sqlite3*) sqlite3_user_data(ctx);
  value = (char*) sqlite3_value_text(values[0]);
  /* Assuming NULL values for type checked columns not allowed */
  if( value == 0 ){
    sqlite3_result_int(ctx, 0);
    return;
  }
  /* Validate type: */
  tmp = 0;
  strtod(value, &tmp);
  if( *tmp != ''\0'' ){
    /* Value does not conform to type */
    sqlite3_result_int(ctx, 0);
    return;
  }
  /* If we got this far value is valid. */
  sqlite3_result_int(ctx, 1);
}

void column_type_udf(
  sqlite3_context *ctx,
  int nargs,
  sqlite3_value **values
){
  sqlite3 *db;
  char *table, *column, *type;
  db = (sqlite3*) sqlite3_user_data(ctx);
  table = (char*) sqlite3_value_text(values[0]);
  column = (char*) sqlite3_value_text(values[1]);
  /* Get declared type from schema */
  type = column_type(db, table, column);
  /* Return type */
  sqlite3_result_text(ctx, type, -1, SQLITE_TRANSIENT);
}

char *column_type(
  sqlite3* db,
  char *table,
  char *column
){
  sqlite3_stmt *stmt;
  int i, len, rc;
  char *sql, *tmp, *type, *p, *sql_type;
  sql = "select %s from %s;";
  tmp = sqlite3_mprintf(sql, column, table);
  rc = sqlite3_prepare(db, tmp, -1, &stmt, 0);
  if( rc != SQLITE_OK ){
    sqlite3_free(tmp);
    return 0;
  }
  sql_type = (char*) sqlite3_column_decltype(stmt, 0);
  /* Convert type to lower case */
  i = 0;
  p = sql_type;
  len = strlen(sql_type);
  type = sqlite3_malloc(len + 1);
  while( i < len ) {
    type[i] = tolower(*p);
    p++;i++;
  }
  type[len] = ''\0'';
  /* Free statement handle and tmp sql string */
  sqlite3_finalize(stmt);
  sqlite3_free(tmp);
  return type;
}

');

.echo on
-- Creating table types.
create table types(
  id integer primary key,
  x int not null default 0,
  y float not null default 0.0
);

-- Populating table types.
insert into types(x,y) values(1,1.1);
insert into types(x,y) values(2,2.1);
insert into types(x,y) values(3,3.1);

-- 1. Add strict typing:
select add_strict_type_check('types', '*');

-- 2. Insert integer value -- should succeed:
insert into types (x) values (1);

-- 3. Update with invalid values -- should fail:
update types set x = 'abc';
update types set y = 'abc';

-- 4. Remove strict typing
select drop_strict_type_check('types', '*');

-- 5. Update with non-integer value -- should succeed:
update types set x = 'not an int';

-- 6. Select records:
.header on
select * from types;

-- 7. Test column_type() UDF
select column_type('types', 'id') as 'id',
       column_type('types', 'x')  as 'x',
       column_type('types', 'y')  as 'y';