File: demo4.c

package info (click to toggle)
spatialite 5.1.0-3
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid, trixie
  • size: 74,240 kB
  • sloc: ansic: 587,051; makefile: 8,583; sh: 4,276; yacc: 1,973; xml: 717
file content (363 lines) | stat: -rw-r--r-- 8,984 bytes parent folder | download | duplicates (4)
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
/* 

demo4.c

Author: Sandro Furieri a.furieri@lqt.it

This software is provided 'as-is', without any express or implied
warranty.  In no event will the author be held liable for any
damages arising from the use of this software.

Permission is granted to anyone to use this software for any
purpose, including commercial applications, and to alter it and
redistribute it freely

*/

#include <stdlib.h>
#include <stdio.h>
#include <string.h>
#include <time.h>

/*
these headers are required in order to support
SQLite/SpatiaLite
*/
#include <sqlite3.h>
#include <spatialite/gaiageo.h>
#include <spatialite.h>

int
main (int argc, char *argv[])
{
    int ret;
    sqlite3 *handle;
    sqlite3_stmt *stmt;
    char sql[256];
    char *err_msg = NULL;
    double x;
    double y;
    int pk;
    int ix;
    int iy;
    gaiaGeomCollPtr geo = NULL;
    unsigned char *blob;
    int blob_size;
    int i;
    char **results;
    int n_rows;
    int n_columns;
    char *count;
    clock_t t0;
    clock_t t1;
    void *cache;


    if (argc != 2)
      {
	  fprintf (stderr, "usage: %s test_db_path\n", argv[0]);
	  return -1;
      }


/* 
trying to connect the test DB: 
- this demo is intended to create a new, empty database
*/
    ret = sqlite3_open_v2 (argv[1], &handle,
			   SQLITE_OPEN_READWRITE | SQLITE_OPEN_CREATE, NULL);
    if (ret != SQLITE_OK)
      {
	  printf ("cannot open '%s': %s\n", argv[1], sqlite3_errmsg (handle));
	  sqlite3_close (handle);
	  return -1;
      }
    cache = spatialite_alloc_connection ();
    spatialite_init_ex (handle, cache, 0);


/* showing the SQLite version */
    printf ("SQLite version: %s\n", sqlite3_libversion ());
/* showing the SpatiaLite version */
    printf ("SpatiaLite version: %s\n", spatialite_version ());
    printf ("\n\n");


/* 
we are supposing this one is an empty database,
so we have to create the Spatial Metadata
*/
    strcpy (sql, "SELECT InitSpatialMetadata(1)");
    ret = sqlite3_exec (handle, sql, NULL, NULL, &err_msg);
    if (ret != SQLITE_OK)
      {
/* some error occurred */
	  printf ("InitSpatialMetadata() error: %s\n", err_msg);
	  sqlite3_free (err_msg);
	  goto abort;
      }


/*
now we can create the test table
for simplicity we'll define only one column, the primary key
*/
    strcpy (sql, "CREATE TABLE test (");
    strcat (sql, "PK INTEGER NOT NULL PRIMARY KEY)");
    ret = sqlite3_exec (handle, sql, NULL, NULL, &err_msg);
    if (ret != SQLITE_OK)
      {
/* an error occurred */
	  printf ("CREATE TABLE 'test' error: %s\n", err_msg);
	  sqlite3_free (err_msg);
	  goto abort;
      }


/*
... we'll add a Geometry column of POINT type to the test table 
*/
    strcpy (sql, "SELECT AddGeometryColumn('test', 'geom', 3003, 'POINT', 2)");
    ret = sqlite3_exec (handle, sql, NULL, NULL, &err_msg);
    if (ret != SQLITE_OK)
      {
/* an error occurred */
	  printf ("AddGeometryColumn() error: %s\n", err_msg);
	  sqlite3_free (err_msg);
	  goto abort;
      }


/*
and finally we'll enable this geo-column to have a Spatial Index based on MBR caching
*/
    strcpy (sql, "SELECT CreateMbrCache('test', 'geom')");
    ret = sqlite3_exec (handle, sql, NULL, NULL, &err_msg);
    if (ret != SQLITE_OK)
      {
/* an error occurred */
	  printf ("CreateMbrCache() error: %s\n", err_msg);
	  sqlite3_free (err_msg);
	  goto abort;
      }

    printf
	("\nnow we are going to insert 1 million POINTs; wait, please ...\n\n");

    t0 = clock ();
/*
beginning a transaction

*** this step is absolutely critical ***

the SQLite engine is a TRANSACTIONAL one
the whole batch of INSERTs has to be performed as an unique transaction,
otherwise performance will be surely very poor
*/
    strcpy (sql, "BEGIN");
    ret = sqlite3_exec (handle, sql, NULL, NULL, &err_msg);
    if (ret != SQLITE_OK)
      {
/* an error occurred */
	  printf ("BEGIN error: %s\n", err_msg);
	  sqlite3_free (err_msg);
	  goto abort;
      }



/* 
preparing to populate the test table
we'll use a Prepared Statement we can reuse in order to insert each row
*/
    strcpy (sql, "INSERT INTO test (pk, geom) VALUES (?, ?)");
    ret = sqlite3_prepare_v2 (handle, sql, strlen (sql), &stmt, NULL);
    if (ret != SQLITE_OK)
      {
/* an error occurred */
	  printf ("INSERT SQL error: %s\n", sqlite3_errmsg (handle));
	  goto abort;
      }

    pk = 0;
    for (ix = 0; ix < 1000; ix++)
      {
	  x = 1000000.0 + (ix * 10.0);
	  for (iy = 0; iy < 1000; iy++)
	    {
/* this double loop will insert 1 million rows into the the test table */

		y = 4000000.0 + (iy * 10.0);
		pk++;
		if ((pk % 25000) == 0)
		  {
		      t1 = clock ();
		      printf ("insert row: %d\t\t[elapsed time: %1.3f]\n",
			      pk, (double) (t1 - t0) / CLOCKS_PER_SEC);
		  }

/* preparing the geometry to insert */
		geo = gaiaAllocGeomColl ();
		geo->Srid = 3003;
		gaiaAddPointToGeomColl (geo, x, y);

/* transforming this geometry into the SpatiaLite BLOB format */
		gaiaToSpatiaLiteBlobWkb (geo, &blob, &blob_size);

/* we can now destroy the geometry object */
		gaiaFreeGeomColl (geo);

/* resetting Prepared Statement and bindings */
		sqlite3_reset (stmt);
		sqlite3_clear_bindings (stmt);

/* binding parameters to Prepared Statement */
		sqlite3_bind_int64 (stmt, 1, pk);
		sqlite3_bind_blob (stmt, 2, blob, blob_size, free);

/* performing actual row insert */
		ret = sqlite3_step (stmt);
		if (ret == SQLITE_DONE || ret == SQLITE_ROW)
		    ;
		else
		  {
/* an unexpected error occurred */
		      printf ("sqlite3_step() error: %s\n",
			      sqlite3_errmsg (handle));
		      sqlite3_finalize (stmt);
		      goto abort;
		  }

	    }
      }
/* we have now to finalize the query [memory cleanup] */
    sqlite3_finalize (stmt);



/*
committing the transaction

*** this step is absolutely critical ***

if we don't confirm the still pending transaction,
any update will be lost
*/
    strcpy (sql, "COMMIT");
    ret = sqlite3_exec (handle, sql, NULL, NULL, &err_msg);
    if (ret != SQLITE_OK)
      {
/* an error occurred */
	  printf ("COMMIT error: %s\n", err_msg);
	  sqlite3_free (err_msg);
	  goto abort;
      }



/*
now we'll optimize the table
*/
    strcpy (sql, "ANALYZE test");
    ret = sqlite3_exec (handle, sql, NULL, NULL, &err_msg);
    if (ret != SQLITE_OK)
      {
/* an error occurred */
	  printf ("ANALYZE error: %s\n", err_msg);
	  sqlite3_free (err_msg);
	  goto abort;
      }


    for (ix = 0; ix < 3; ix++)
      {
	  printf ("\nperforming test#%d - not using Spatial Index\n", ix);
/* 
now we'll perform the spatial query WITHOUT using the Spatial Index
we'll loop 3 times in order to avoid buffering-caching side effects
*/
	  strcpy (sql, "SELECT Count(*) FROM test ");
	  strcat (sql, "WHERE MbrWithin(geom, BuildMbr(");
	  strcat (sql, "1000400.5, 4000400.5, ");
	  strcat (sql, "1000450.5, 4000450.5))");
	  t0 = clock ();
	  ret = sqlite3_get_table (handle, sql, &results, &n_rows, &n_columns,
				   &err_msg);
	  if (ret != SQLITE_OK)
	    {
/* an error occurred */
		printf ("NoSpatialIndex SQL error: %s\n", err_msg);
		sqlite3_free (err_msg);
		goto abort;
	    }
	  count = "";
	  for (i = 1; i <= n_rows; i++)
	    {
		count = results[(i * n_columns) + 0];
	    }
	  t1 = clock ();
	  printf ("Count(*) = %d\t\t[elapsed time: %1.4f]\n", atoi (count),
		  (double) (t1 - t0) / CLOCKS_PER_SEC);
/* we can now free the table results */
	  sqlite3_free_table (results);
      }


    for (ix = 0; ix < 3; ix++)
      {
	  printf ("\nperforming test#%d - using the MBR cache Spatial Index\n",
		  ix);
/* 
now we'll perform the spatial query USING the MBR cache Spatial Index
we'll loop 3 times in order to avoid buffering-caching side effects
*/
	  strcpy (sql, "SELECT Count(*) FROM test ");
	  strcat (sql, "WHERE ROWID IN (");
	  strcat (sql, "SELECT rowid FROM cache_test_geom WHERE ");
	  strcat (sql,
		  "mbr = FilterMbrWithin(1000400.5, 4000400.5, 1000450.5, 4000450.5))");

/*
YES, this query is a very unhappy one
the idea is simply to simulate exactly the same conditions as above
*/
	  t0 = clock ();
	  ret = sqlite3_get_table (handle, sql, &results, &n_rows, &n_columns,
				   &err_msg);
	  if (ret != SQLITE_OK)
	    {
/* an error occurred */
		printf ("SpatialIndex SQL error: %s\n", err_msg);
		sqlite3_free (err_msg);
		goto abort;
	    }
	  count = "";
	  for (i = 1; i <= n_rows; i++)
	    {
		count = results[(i * n_columns) + 0];
	    }
	  t1 = clock ();
	  printf ("Count(*) = %d\t\t[elapsed time: %1.4f]\n", atoi (count),
		  (double) (t1 - t0) / CLOCKS_PER_SEC);
/* we can now free the table results */
	  sqlite3_free_table (results);
      }


/* disconnecting the test DB */
    ret = sqlite3_close (handle);
    if (ret != SQLITE_OK)
      {
	  printf ("close() error: %s\n", sqlite3_errmsg (handle));
	  return -1;
      }
    printf ("\n\nsample successfully terminated\n");
    spatialite_cleanup_ex (cache);
    return 0;

  abort:
    sqlite3_close (handle);
    spatialite_cleanup_ex (cache);
    spatialite_shutdown();
    return -1;
}