Over a million developers have joined DZone.

Add A Concat() Aggregate Function To SQLite

I often need string concatenation to behave just like an aggregate function.
Once again I find a need to do that in SQLite, and to do that without recompiling
SQLite for every platform we distribute for... 

#include "sqlite3ext.h"

typedef struct SCtx SCtx;
struct SCtx {
  int rowCnt;
  int charCnt;
  char *result;

static void concat_step(sqlite3_context* ctx, int argc, sqlite3_value**argv) {

  SCtx *p = (SCtx *) sqlite3_aggregate_context(ctx, sizeof(*p));

  char *sep = sqlite3_value_text(argv[1]);

  char *txt = sqlite3_value_text(argv[0]);

  if (p->rowCnt) {
    char *txt2 = malloc(strlen(txt) + strlen(sep) + 1);
    txt = txt2;

  //  printf("%d. Txt: [%s] len %d\n", p->rowCnt, txt, strlen(txt));

  int len = strlen(txt);

  if (!p->result) {
    p->result = malloc(len + 1);
    strcpy(p->result, txt);
  } else {
    p->result = realloc(p->result, strlen(p->result) + len + 1);
  //  printf ("intermediate [%s]\n", p->result);

static void concat_final(sqlite3_context* ctx,
                         int argc,
                         sqlite3_value** argv) {

  SCtx *p = (SCtx *) sqlite3_aggregate_context(ctx, sizeof(*p));
  //  printf("Finally: %s\n", p->result);
  sqlite3_result_text(ctx,  p->result, strlen(p->result), NULL);

int sqlite3_extension_init(
  sqlite3 *db,
  char **pzErrMsg,
  const sqlite3_api_routines *pApi
  sqlite3_create_function(db, "concat", 2, SQLITE_ANY, 0, NULL, concat_step, concat_final);
  return 0;

I compiled this with the following (here, ./src is the SQLite code - I used

gcc -fpic -c agg.c -I./src
gcc -shared -Wl,-soname,libagg.so -o libagg.so agg.o

And here's how it works:

sqlite> CREATE TABLE test (animals VARCHAR, interjection VARCHAR);

sqlite> insert into test (animals, interjection) values ('lions', 'oh my');

sqlite> insert into test (animals, interjection) values ('tigers', 'oh my'); 

sqlite> insert into test (animals, interjection) values ('bears', 'oh my');

sqlite> select load_extension('./libagg.so');

sqlite> select concat(animals, ' and '), interjection from test group by interjection;

sqlite> lions and tigers and bears|oh my

See also:
1. http://www.sqlite.org/cvstrac/wiki?p=LoadableExtensions
2. http://souptonuts.sourceforge.net/readme_sqlite_tutorial.html
3. http://www.sqlite.org/capi3ref.html

{{ parent.title || parent.header.title}}

{{ parent.tldr }}

{{ parent.urlSource.name }}