├── .gitignore ├── CONTRIBUTING.md ├── LICENSE ├── Makefile ├── README.md ├── contributors.txt ├── db2util.c ├── db2util.h ├── format_csv.c ├── format_csv.h ├── format_json.c ├── format_json.h ├── format_space.c └── format_space.h /.gitignore: -------------------------------------------------------------------------------- 1 | db2util 2 | *.o 3 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | # Contributing 2 | 3 | ## Contributing In General 4 | 5 | Our project welcomes external contributions. If you have an itch, please feel 6 | free to scratch it. 7 | 8 | To contribute code or documentation, please submit a [pull request](https://github.com/IBM/python-itoolkit/pulls). 9 | 10 | A good way to familiarize yourself with the codebase and contribution process is 11 | to look for and tackle low-hanging fruit in the [issue tracker](https://github.com/IBM/python-itoolkit/issues). 12 | These will be marked with the [good first issue](https://github.com/IBM/python-itoolkit/issues?q=is%3Aissue+is%3Aopen+label%3A%22good+first+issue%22) label. You may also want to look at those marked with [help wanted](https://github.com/IBM/python-itoolkit/issues?q=is%3Aissue+is%3Aopen+label%3A%22help+wanted%22). 13 | 14 | **Note: We appreciate your effort, and want to avoid a situation where a contribution 15 | requires extensive rework (by you or by us), sits in backlog for a long time, or 16 | cannot be accepted at all!** 17 | 18 | ### Proposing new features 19 | 20 | If you would like to implement a new feature, please [raise an issue](https://github.com/IBM/python-itoolkit/issues) 21 | before sending a pull request so the feature can be discussed. This is to avoid 22 | you wasting your valuable time working on a feature that the project developers 23 | are not interested in accepting into the code base. 24 | 25 | ### Fixing bugs 26 | 27 | If you would like to fix a bug, please [raise an issue](https://github.com/IBM/python-itoolkit/issues) before sending a 28 | pull request so it can be tracked. 29 | 30 | ## Legal 31 | 32 | We have tried to make it as easy as possible to make contributions. This 33 | applies to how we handle the legal aspects of contribution. We use the 34 | same approach - the [Developer's Certificate of Origin 1.1 (DCO)](https://github.com/hyperledger/fabric/blob/master/docs/source/DCO1.1.txt) - that the Linux® Kernel [community](https://elinux.org/Developer_Certificate_Of_Origin) 35 | uses to manage code contributions. 36 | 37 | We simply ask that when submitting a patch for review, the developer 38 | must include a sign-off statement in the commit message. 39 | 40 | Here is an example Signed-off-by line, which indicates that the 41 | submitter accepts the DCO: 42 | 43 | ```text 44 | Signed-off-by: John Doe 45 | ``` 46 | 47 | You can include this automatically when you commit a change to your 48 | local git repository using the following command: 49 | 50 | ```bash 51 | git commit -s 52 | ``` 53 | 54 | ## Communication 55 | 56 | Please feel free to connect with us on our [Ryver forum](https://ibmioss.ryver.com/index.html#forums/1000126). You can join the Ryver community [here](https://ibmioss.ryver.com/application/signup/members/9tJsXDG7_iSSi1Q). 57 | 58 | 59 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2016 International Business Machines Corp. 2 | Copyright (c) 2016 Krengel Technology, Inc. 3 | 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), 6 | to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, 7 | and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: 8 | 9 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. 10 | 11 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 12 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 13 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS 14 | IN THE SOFTWARE. 15 | 16 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | ### make 2 | PREFIX=/QOpenSys/pkgs 3 | BINDIR=$(PREFIX)/bin 4 | LIBDIR=$(PREFIX)/lib 5 | 6 | CC=gcc 7 | CPPFLAGS=-I/QOpenSys/pkgs/include/cli 8 | CFLAGS=-g -maix64 -Wall 9 | LDFLAGS=-maix64 -ldb400 -Wl,-blibpath:/QOpenSys/usr/lib 10 | 11 | all: db2util 12 | 13 | ### generic rules 14 | ### (note: .c.o compiles all c parts in OBJS list) 15 | .SUFFIXES: .o .c 16 | 17 | db2util: db2util.o format_json.o format_csv.o format_space.o 18 | $(CC) -o $@ $(LDFLAGS) -o $@ $^ 19 | 20 | install: db2util 21 | mkdir -p $(DESTDIR)$(BINDIR) 22 | cp db2util $(DESTDIR)$(BINDIR) 23 | 24 | clean: 25 | rm *.o db2util 26 | 27 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # IBM i db2util 2 | 3 | ## :rotating_light: ------ IMPORTANT WARNING ------- :rotating_light: 4 | 5 | This project is (and possibly always will be) under construction. It is released as a stable version 1.0.0. Future major releases may break compatibility. 6 | 7 | ## About 8 | 9 | Welcome to the db2util project. This project includes a `db2util` command which is similar to the `db2` command provided by `QSH` on IBM i, but runs from PASE and interfaces through libdb400.a. 10 | 11 | ## Building 12 | 13 | This project uses a very simple Makefile with no configuration step: 14 | 15 | ```sh 16 | make 17 | make install 18 | ``` 19 | 20 | The project can be configured using the following Makefile variables: 21 | 22 | - `PREFIX` - the install prefix, default: `/QOpenSys/pkgs` 23 | - `BINDIR` - the install path for binaries, default `/QOpenSys/pkgs/bin` 24 | - `CC` - the compiler, default: `gcc` 25 | - `CPPFLAGS` - the C pre-processor flags, eg. `-I`, `-D`, ... 26 | - `CFLAGS` - the C compiler flags 27 | - `LDFLAGS` - the linker flags 28 | - `DESTDIR` - set the install destination prefix, useful for installing in to a temporary directory for packaging 29 | 30 | ## Build Dependencies 31 | 32 | In order to build you will need: 33 | 34 | - GNU make 35 | - GCC 36 | - PASE CLI headers 37 | 38 | You can use the following command to install them: 39 | 40 | ```sh 41 | yum install gcc make-gnu sqlcli-devel 42 | ``` 43 | 44 | ## Compiled version 45 | 46 | A pre-compiled version is available from the IBM i yum repository: 47 | 48 | ```sh 49 | yum install db2util 50 | ``` 51 | 52 | **NOTE: See [here](http://ibm.biz/ibmi-rpms) for more information on getting `yum` installed on your IBM i system.** 53 | 54 | ## Usage 55 | 56 | ### Comma delimter output (default or with `-o csv`) 57 | 58 | ```sh 59 | db2util "select * from QIWS/QCUSTCDT where LSTNAM='Jones' or LSTNAM='Vine'" 60 | "839283","Jones ","B D","21B NW 135 St","Clay ","NY","13041","400","1","100.00","0.00" 61 | "392859","Vine ","S S","PO Box 79 ","Broton","VT","5046","700","1","439.00","0.00" 62 | ``` 63 | 64 | ### JSON output `(-o json`) 65 | 66 | The original JSON format returns an array of objects inside an object with a single key "records". The whole encasing object is redundant. The new JSON format returns only an array of object records. The only difference between the two is the removal of the redundant encasing object. 67 | 68 | To switch between the two formats, use the `DB2UTIL_JSON_CONTAINER` environment variable. If this variable is unset or contains "object", the old format will be returned. If it's set to "array", the new format will be returned. Any other value will cause an error message to be displayed and the command to exit. 69 | 70 | **NOTE: It is advised to always set `DB2UTIL_JSON_CONTAINER` to your preferred format, as the default value may change in a future version** 71 | 72 | - Array container 73 | 74 | ```sh 75 | export DB2UTIL_JSON_CONTAINER=array 76 | 77 | db2util -o json "select * from QIWS/QCUSTCDT where LSTNAM='Jones' or LSTNAM='Vine'" 78 | [ 79 | {"CUSNUM":839283,"LSTNAM":"Jones ","INIT":"B D","STREET":"21B NW 135 St","CITY":"Clay ","STATE":"NY","ZIPCOD":13041,"CDTLMT":400,"CHGCOD":1,"BALDUE":100.00,"CDTDUE":0.00}, 80 | {"CUSNUM":392859,"LSTNAM":"Vine ","INIT":"S S","STREET":"PO Box 79 ","CITY":"Broton","STATE":"VT","ZIPCOD":5046,"CDTLMT":700,"CHGCOD":1,"BALDUE":439.00,"CDTDUE":0.00} 81 | ] 82 | ``` 83 | 84 | - Object container (deprecated) 85 | 86 | ```sh 87 | export DB2UTIL_JSON_CONTAINER=object 88 | 89 | db2util -o json "select * from QIWS/QCUSTCDT where LSTNAM='Jones' or LSTNAM='Vine'" 90 | {"records":[ 91 | {"CUSNUM":839283,"LSTNAM":"Jones ","INIT":"B D","STREET":"21B NW 135 St","CITY":"Clay ","STATE":"NY","ZIPCOD":13041,"CDTLMT":400,"CHGCOD":1,"BALDUE":100.00,"CDTDUE":0.00}, 92 | {"CUSNUM":392859,"LSTNAM":"Vine ","INIT":"S S","STREET":"PO Box 79 ","CITY":"Broton","STATE":"VT","ZIPCOD":5046,"CDTLMT":700,"CHGCOD":1,"BALDUE":439.00,"CDTDUE":0.00} 93 | ]} 94 | ``` 95 | 96 | ### Space delimter output (`-o space`) 97 | 98 | ```sh 99 | db2util -o space "select * from QIWS/QCUSTCDT where LSTNAM='Jones' or LSTNAM='Vine'" 100 | "839283" "Jones " "B D" "21B NW 135 St" "Clay " "NY" "13041" "400" "1" "100.00" "0.00" 101 | "392859" "Vine " "S S" "PO Box 79 " "Broton" "VT" "5046" "700" "1" "439.00" "0.00" 102 | ``` 103 | 104 | ### Help 105 | 106 | ```sh 107 | db2util -h 108 | db2util [options] 109 | Options: 110 | -o Output format. Value values for fmt: 111 | json: [{"name"}:{"value"},{"name"}:{"value"},...] 112 | csv: "value","value",... 113 | space: "value" "value" ... 114 | -p Input parameter(s) (max 32) 115 | -h This help text 116 | -v Show version number and quit 117 | 118 | Examples: 119 | db2util "select * from QIWS.QCUSTCDT where LSTNAM='Jones' or LSTNAM='Vine'" 120 | db2util -p Jones -p Vine -o json "select * from QIWS.QCUSTCDT where LSTNAM=? or LSTNAM=?" 121 | db2util -p Jones -p Vine -o space "select * from QIWS.QCUSTCDT where LSTNAM=? or LSTNAM=?" 122 | ``` 123 | 124 | ## Contributing 125 | 126 | Please read the [contribution guidelines](CONTRIBUTING.md). 127 | 128 | ## Contributors 129 | 130 | See [contributors.txt](contributors.txt). 131 | 132 | ## License 133 | 134 | [MIT](LICENSE) 135 | 136 | (This project has been migrated from [http://bitbucket.org/litmis/db2util](http://bitbucket.org/litmis/db2util)) 137 | -------------------------------------------------------------------------------- /contributors.txt: -------------------------------------------------------------------------------- 1 | Tony Cairns (IBM) 2 | Jesse Gorzinski (IBM) 3 | Kevin Adler (IBM) 4 | -------------------------------------------------------------------------------- /db2util.c: -------------------------------------------------------------------------------- 1 | #include 2 | #include 3 | #include 4 | #include 5 | 6 | #include "db2util.h" 7 | 8 | #include "format_json.h" 9 | #include "format_csv.h" 10 | #include "format_space.h" 11 | 12 | enum { 13 | FORMAT_JSON, 14 | FORMAT_CSV, 15 | FORMAT_SPACE 16 | }; 17 | 18 | format_t* formats[] = { 19 | &json_format, 20 | &csv_format, 21 | &space_format 22 | }; 23 | 24 | /* 25 | check_error(henv, SQL_HANDLE_ENV, rc); 26 | check_error(hdbc, SQL_HANDLE_DBC, rc); 27 | check_error(hstmt, SQL_HANDLE_STMT, rc); 28 | */ 29 | static void check_error(SQLHANDLE handle, SQLSMALLINT hType, SQLRETURN rc) 30 | { 31 | SQLCHAR msg[SQL_MAX_MESSAGE_LENGTH + 1]; 32 | SQLCHAR sqlstate[SQL_SQLSTATE_SIZE+1]; 33 | SQLINTEGER sqlcode = 0; 34 | SQLSMALLINT length = 0; 35 | 36 | if (rc != SQL_ERROR) return; 37 | 38 | memset(msg, '\0', sizeof(msg)); 39 | memset(sqlstate, '\0', sizeof(sqlstate)); 40 | 41 | if ( SQLGetDiagRec(hType, handle, 1, sqlstate, &sqlcode, msg, sizeof(msg), &length) != SQL_SUCCESS ) { 42 | fprintf(stderr, "Critical error: couldn't retrieve error info\n"); 43 | exit(1); 44 | } 45 | 46 | char* p; 47 | while ((p = strchr(msg, '\n'))) { 48 | *p = '\0'; 49 | } 50 | 51 | fprintf(stderr, "%s SQLSTATE=%s SQLCODE=%d\n", msg, sqlstate, (int)sqlcode); 52 | exit(1); 53 | } 54 | 55 | static inline void set_env_attrs(SQLHENV henv) { 56 | SQLRETURN rc; 57 | SQLINTEGER attr = SQL_TRUE; 58 | 59 | rc = SQLSetEnvAttr(henv, SQL_ATTR_SERVER_MODE, &attr, 0); 60 | check_error(henv, SQL_HANDLE_ENV, rc); 61 | 62 | attr = SQL_FALSE; 63 | rc = SQLSetEnvAttr(henv, SQL_ATTR_INCLUDE_NULL_IN_LEN, &attr, 0); 64 | check_error(henv, SQL_HANDLE_ENV, rc); 65 | } 66 | 67 | static inline void set_conn_attrs(SQLHDBC hdbc) { 68 | SQLRETURN rc; 69 | SQLINTEGER attr = SQL_TRUE; 70 | 71 | rc = SQLSetConnectAttr(hdbc, SQL_ATTR_DBC_SYS_NAMING, &attr, 0); 72 | check_error(hdbc, SQL_HANDLE_DBC, rc); 73 | 74 | rc = SQLSetConnectAttr(hdbc, SQL_ATTR_NULLT_ARRAY_RESULTS, &attr, 0); 75 | check_error(hdbc, SQL_HANDLE_DBC, rc); 76 | 77 | rc = SQLSetConnectAttr(hdbc, SQL_ATTR_NULLT_OUTPUT_PARMS, &attr, 0); 78 | check_error(hdbc, SQL_HANDLE_DBC, rc); 79 | 80 | attr = SQL_TXN_NO_COMMIT; 81 | rc = SQLSetConnectAttr(hdbc, SQL_ATTR_TXN_ISOLATION, &attr, 0); 82 | check_error(hdbc, SQL_HANDLE_DBC, rc); 83 | } 84 | 85 | static int db2util_query(char* stmt, int fmt, int argc, const char* argv[]) { 86 | SQLRETURN rc = 0; 87 | SQLHENV henv = 0; 88 | SQLHDBC hdbc = 0; 89 | SQLHSTMT hstmt = 0; 90 | SQLSMALLINT param_count = 0; 91 | SQLSMALLINT column_count = 0; 92 | 93 | 94 | SQLOverrideCCSID400(1208); 95 | 96 | /* env */ 97 | rc = SQLAllocHandle(SQL_HANDLE_ENV, SQL_NULL_HANDLE, &henv); 98 | check_error(henv, SQL_HANDLE_ENV, rc); 99 | set_env_attrs(henv); 100 | 101 | /* connect */ 102 | rc = SQLAllocHandle(SQL_HANDLE_DBC, henv, &hdbc); 103 | check_error(hdbc, SQL_HANDLE_DBC, rc); 104 | 105 | rc = SQLConnect(hdbc, NULL, 0, NULL, 0, NULL, 0); 106 | check_error(hdbc, SQL_HANDLE_DBC, rc); 107 | set_conn_attrs(hdbc); 108 | 109 | 110 | /* statement */ 111 | rc = SQLAllocHandle(SQL_HANDLE_STMT, hdbc, &hstmt); 112 | check_error(hstmt, SQL_HANDLE_STMT, rc); 113 | 114 | /* prepare */ 115 | rc = SQLPrepare(hstmt, (SQLCHAR*)stmt, SQL_NTS); 116 | check_error(hstmt, SQL_HANDLE_STMT, rc); 117 | 118 | /* number of input parms */ 119 | rc = SQLNumParams(hstmt, ¶m_count); 120 | check_error(hstmt, SQL_HANDLE_STMT, rc); 121 | 122 | if (param_count != argc) { 123 | fprintf(stderr, "Invalid parameter count: expected %d got %d\n", param_count, argc); 124 | exit(1); 125 | } 126 | 127 | SQLINTEGER input_indicator = SQL_NTS; 128 | for (int i = 0; i < param_count; i++) { 129 | const char* arg = argv[i]; 130 | size_t precision = strlen(arg); 131 | 132 | // NOTE: We specify SQL_CHAR since that saves calling SQLDescribeParam to 133 | // get the actual type and SQLBindParameter doesn't use this value 134 | // unless we specify SQL_C_DEFAULT anyway. 135 | rc = SQLBindParameter(hstmt, i+1, SQL_PARAM_INPUT, SQL_C_CHAR, SQL_CHAR, 136 | precision, 0, (SQLCHAR*) arg, 0, &input_indicator); 137 | check_error(hstmt, SQL_HANDLE_STMT, rc); 138 | } 139 | 140 | /* execute */ 141 | rc = SQLExecute(hstmt); 142 | check_error(hstmt, SQL_HANDLE_STMT, rc); 143 | 144 | /* result set */ 145 | rc = SQLNumResultCols(hstmt, &column_count); 146 | check_error(hstmt, SQL_HANDLE_STMT, rc); 147 | 148 | if (column_count < 1) exit(0); 149 | 150 | col_info_t* cols = malloc(sizeof(col_info_t) * column_count); 151 | 152 | for (int i = 0 ; i < column_count; i++) { 153 | col_info_t* col = &cols[i]; 154 | 155 | SQLINTEGER size; 156 | 157 | // IBM i CLI doesn't allow passing NULL for parameters we 158 | // don't care about, so we just pass a field and ignore it. 159 | SQLSMALLINT ignore __attribute__((unused)); 160 | 161 | rc = SQLDescribeCol(hstmt, i+1, col->name, sizeof(col->name), &ignore, &col->type, &size, &ignore, &ignore); 162 | check_error(hstmt, SQL_HANDLE_STMT, rc); 163 | 164 | size_t bind_length; 165 | switch (col->type) { 166 | case SQL_CHAR: 167 | case SQL_VARCHAR: 168 | case SQL_CLOB: 169 | case SQL_DBCLOB: 170 | case SQL_UTF8_CHAR: 171 | case SQL_WCHAR: 172 | case SQL_WVARCHAR: 173 | case SQL_GRAPHIC: 174 | case SQL_VARGRAPHIC: 175 | case SQL_XML: 176 | default: 177 | col->bind_type = SQL_C_CHAR; 178 | col->buffer_length = bind_length = size * 3; 179 | col->buffer = col->data = col->bind_ptr = malloc(col->buffer_length); 180 | break; 181 | 182 | case SQL_BINARY: 183 | case SQL_VARBINARY: 184 | case SQL_BLOB: 185 | col->bind_type = SQL_C_CHAR; 186 | col->buffer_length = bind_length = size * 3; 187 | col->buffer = col->data = col->bind_ptr = malloc(col->buffer_length); 188 | break; 189 | 190 | case SQL_DECFLOAT: 191 | case SQL_REAL: 192 | case SQL_FLOAT: 193 | case SQL_DOUBLE: 194 | case SQL_DECIMAL: 195 | case SQL_NUMERIC: 196 | // JSON is particular about its number formats and wants always a leading 197 | // zero when less than 1, which Db2 does not do. To accomodate this, we 198 | // reserve space for the leading zero by setting bind_ptr 1 byte in to 199 | // the allocated buffer. When needed, the fetch code below can use this 200 | // reserved byte to insert a leading zero and adjust the data pointer to 201 | // point to the new start of the data. 202 | col->bind_type = SQL_C_CHAR; 203 | col->buffer_length = 100; 204 | col->buffer = malloc(col->buffer_length); 205 | col->data = col->bind_ptr = col->buffer + 1; 206 | bind_length = col->buffer_length - 1; 207 | break; 208 | 209 | case SQL_TYPE_DATE: 210 | case SQL_TYPE_TIME: 211 | case SQL_TYPE_TIMESTAMP: 212 | case SQL_DATETIME: 213 | case SQL_BIGINT: 214 | case SQL_SMALLINT: 215 | case SQL_INTEGER: 216 | col->bind_type = SQL_C_CHAR; 217 | col->buffer_length = bind_length = 100; 218 | col->buffer = col->data = col->bind_ptr = malloc(col->buffer_length); 219 | break; 220 | } 221 | 222 | rc = SQLBindCol(hstmt, i+1, col->bind_type, col->bind_ptr, bind_length, &col->ind); 223 | check_error(hstmt, SQL_HANDLE_STMT, rc); 224 | } 225 | 226 | format_t* format = formats[fmt]; 227 | 228 | void* state = format->new(); 229 | format->start_rows(stdout, state); 230 | 231 | while ((rc = SQLFetch(hstmt)) == SQL_SUCCESS) { 232 | for (int i = 0; i < column_count; ++i) { 233 | col_info_t* col = cols + i; 234 | 235 | if (col->ind == SQL_NTS) { 236 | col->ind = strlen(col->bind_ptr); 237 | } 238 | 239 | switch(col->type) { 240 | case SQL_DECIMAL: 241 | case SQL_NUMERIC: 242 | case SQL_DECFLOAT: 243 | case SQL_REAL: 244 | case SQL_FLOAT: 245 | case SQL_DOUBLE: 246 | if (col->ind == SQL_NULL_DATA) break; 247 | 248 | // If needed add leading zero & adjust data pointer and length 249 | // 250 | // NOTE: bind_ptr was set to to &buffer[1] before binding 251 | if (col->buffer[1] == '.') { 252 | // Positive number less than 1 253 | // Insert a leading 0 254 | // eg. .12345 -> 0.12345 255 | col->buffer[0] = '0'; 256 | col->data = col->buffer; 257 | col->ind++; 258 | } 259 | else if (col->buffer[1] == '-' && col->buffer[2] == '.') { 260 | // Negative number less than 1 261 | // Move sign to the left and insert a 0 262 | // eg. -.54321 -> -0.54321 263 | col->buffer[0] = '-'; 264 | col->buffer[1] = '0'; 265 | col->data = col->buffer; 266 | col->ind++; 267 | } 268 | else { 269 | // Positive or negative number greater than or equal to 1 270 | // 271 | // No adjustment needed, but we still need to explicitly set data in 272 | // case it was adjusted for a previous row 273 | col->data = col->bind_ptr; 274 | } 275 | break; 276 | 277 | default: 278 | break; 279 | } 280 | } 281 | 282 | format->row(stdout, state, cols, column_count); 283 | 284 | for (int i = 0; i < column_count; ++i) { 285 | cols[i].ind = cols[i].buffer_length; 286 | } 287 | } 288 | 289 | format->end_rows(stdout, state); 290 | format->free(state); 291 | 292 | for (int i = 0 ; i < column_count; i++) { 293 | free(cols[i].buffer); 294 | } 295 | free(cols); 296 | 297 | rc = SQLFreeHandle(SQL_HANDLE_STMT, hstmt); 298 | rc = SQLDisconnect(hdbc); 299 | rc = SQLFreeHandle(SQL_HANDLE_DBC, hdbc); 300 | /* SQLFreeHandle(SQL_HANDLE_ENV, henv); */ 301 | return rc; 302 | } 303 | 304 | #define STR(s) #s 305 | #define XSTR(s) STR(s) 306 | 307 | static void exit_with_usage(const char* program, int rc) { 308 | printf("%s [options] \n", program); 309 | printf("Options:\n"); 310 | printf(" -o Output format. Value values for fmt:\n"); 311 | printf(" json: [{\"name\"}:{\"value\"},{\"name\"}:{\"value\"},...]\n"); 312 | printf(" csv: \"value\",\"value\",...\n"); 313 | printf(" space: \"value\" \"value\" ...\n"); 314 | printf(" -p Input parameter(s) (max " XSTR(DB2UTIL_MAX_ARGS) ")\n"); 315 | printf(" -h This help text\n"); 316 | printf(" -v Show version number and quit\n"); 317 | printf("\nExamples:\n"); 318 | printf("%s \"select * from QIWS.QCUSTCDT where LSTNAM='Jones' or LSTNAM='Vine'\"\n", program); 319 | printf("%s -p Jones -p Vine -o json \"select * from QIWS.QCUSTCDT where LSTNAM=? or LSTNAM=?\"\n", program); 320 | printf("%s -p Jones -p Vine -o space \"select * from QIWS.QCUSTCDT where LSTNAM=? or LSTNAM=?\"\n", program); 321 | 322 | exit(rc); 323 | } 324 | 325 | int main(int argc, char* const* argv) { 326 | int parm_count = 0; 327 | static const char* parms[DB2UTIL_MAX_ARGS]; 328 | int format = FORMAT_CSV; 329 | 330 | int opt; 331 | while ((opt = getopt(argc, argv, "hvo:p:")) != -1) { 332 | switch(opt) { 333 | case 'h': 334 | exit_with_usage(argv[0], 0); 335 | 336 | case 'v': 337 | printf("db2util " DB2UTIL_VERSION "\n"); 338 | return 0; 339 | 340 | case 'o': 341 | if (strcmp(optarg, "json") == 0) { 342 | format = FORMAT_JSON; 343 | } 344 | else if (strcmp(optarg, "comma") == 0 || 345 | strcmp(optarg, "csv") == 0) { 346 | format = FORMAT_CSV; 347 | } 348 | else if (strcmp(optarg, "space") == 0) { 349 | format = FORMAT_SPACE; 350 | } 351 | else { 352 | exit_with_usage(argv[0], 1); 353 | } 354 | break; 355 | 356 | case 'p': 357 | if (parm_count == DB2UTIL_MAX_ARGS) { 358 | fprintf(stderr, "Exceeded the max # of input arguments (%d)\n", DB2UTIL_MAX_ARGS); 359 | return 1; 360 | } 361 | 362 | parms[parm_count++] = optarg; 363 | break; 364 | 365 | case '?': 366 | case ':': 367 | exit_with_usage(argv[0], 1); 368 | } 369 | } 370 | 371 | if (argc - optind != 1) { 372 | exit_with_usage(argv[0], 1); 373 | } 374 | 375 | db2util_query(argv[optind], format, parm_count, parms); 376 | 377 | return 0; 378 | } 379 | -------------------------------------------------------------------------------- /db2util.h: -------------------------------------------------------------------------------- 1 | #ifndef DB2UTIL_H 2 | #define DB2UTIL_H 3 | 4 | #include 5 | #include 6 | #include 7 | 8 | #define DB2UTIL_VERSION "1.0.13-dev" 9 | #define DB2UTIL_MAX_ARGS 32 10 | 11 | typedef struct { 12 | SQLSMALLINT type; 13 | SQLSMALLINT bind_type; 14 | SQLINTEGER ind; 15 | char* buffer; 16 | char* bind_ptr; 17 | char* data; 18 | size_t buffer_length; 19 | char name[129]; 20 | } col_info_t; 21 | 22 | typedef void* (*format_new_t)(void); 23 | typedef void (*format_free_t)(void*); 24 | typedef void (*format_row_t)(FILE*, void*, col_info_t*, int); 25 | typedef void (*format_start_rows_t)(FILE*, void*); 26 | typedef void (*format_end_rows_t)(FILE*, void*); 27 | 28 | 29 | typedef struct { 30 | format_new_t new; 31 | format_free_t free; 32 | format_row_t row; 33 | format_start_rows_t start_rows; 34 | format_end_rows_t end_rows; 35 | } format_t; 36 | 37 | #endif 38 | -------------------------------------------------------------------------------- /format_csv.c: -------------------------------------------------------------------------------- 1 | #include 2 | 3 | #include "db2util.h" 4 | 5 | 6 | static void* csv_format_new(void) { 7 | return NULL; 8 | } 9 | 10 | static void csv_format_free(void* st) {} 11 | 12 | static void csv_row(FILE* f, void* state, col_info_t* cols, int count) { 13 | const char* separator = ""; 14 | 15 | for(int i = 0; i < count; ++i) { 16 | col_info_t* col = &cols[i]; 17 | 18 | const char* buffer = col->data; 19 | int length = col->ind; 20 | 21 | if(length == SQL_NULL_DATA) { 22 | buffer = "null"; 23 | length = 4; 24 | } 25 | 26 | printf("%s\"", separator); 27 | 28 | for (int y = 0; y < length; y++) { 29 | if (buffer[y] == '"') { 30 | putchar('"'); 31 | } 32 | putchar(buffer[y]); 33 | } 34 | 35 | putchar('"'); 36 | 37 | separator = ","; 38 | } 39 | 40 | printf("\n"); 41 | } 42 | 43 | static void csv_start_rows(FILE* f, void* state) {} 44 | 45 | static void csv_end_rows(FILE* f, void* state) {} 46 | 47 | format_t csv_format = { 48 | csv_format_new, 49 | csv_format_free, 50 | csv_row, 51 | csv_start_rows, 52 | csv_end_rows 53 | }; 54 | -------------------------------------------------------------------------------- /format_csv.h: -------------------------------------------------------------------------------- 1 | #ifndef FORMAT_CSV_H 2 | #define FORMAT_CSV_H 3 | 4 | #include "db2util.h" 5 | 6 | extern format_t csv_format; 7 | 8 | #endif -------------------------------------------------------------------------------- /format_json.c: -------------------------------------------------------------------------------- 1 | #include 2 | #include 3 | 4 | #include "db2util.h" 5 | 6 | struct state { 7 | const char* row_separator; 8 | const char* start_extra; 9 | const char* end_extra; 10 | }; 11 | 12 | 13 | static void* json_format_new(void) { 14 | struct state* st = malloc(sizeof(struct state)); 15 | 16 | st->row_separator = ""; 17 | 18 | const char* json_format = getenv("DB2UTIL_JSON_CONTAINER"); 19 | if (!json_format || strcmp(json_format, "object") == 0) { 20 | st->start_extra = "{\"records\":"; 21 | st->end_extra = "}\n"; 22 | } 23 | else if (strcmp(json_format, "array") == 0) { 24 | st->start_extra = ""; 25 | st->end_extra = ""; 26 | } 27 | else { 28 | fprintf(stderr, "Invalid value for DB2UTIL_JSON_CONTAINER: %s\n", json_format); 29 | exit(2); 30 | } 31 | 32 | return st; 33 | } 34 | 35 | static void json_format_free(void* st) { 36 | free(st); 37 | } 38 | 39 | static void json_row(FILE* f, void* state, col_info_t* cols, int count) { 40 | struct state* st = state; 41 | 42 | printf("%s{", st->row_separator); 43 | st->row_separator = ",\n"; 44 | 45 | const char* quote; 46 | 47 | const char* comma = ""; 48 | for(int i = 0; i < count; ++i) { 49 | col_info_t* col = &cols[i]; 50 | 51 | switch(col->type) { 52 | case SQL_BIGINT: 53 | case SQL_DECFLOAT: 54 | case SQL_SMALLINT: 55 | case SQL_INTEGER: 56 | case SQL_REAL: 57 | case SQL_FLOAT: 58 | case SQL_DOUBLE: 59 | case SQL_DECIMAL: 60 | case SQL_NUMERIC: 61 | quote = ""; 62 | break; 63 | 64 | default: 65 | quote = "\""; 66 | break; 67 | } 68 | 69 | const char* buffer = col->data; 70 | int length = col->ind; 71 | 72 | if(length == SQL_NULL_DATA) { 73 | buffer = "null"; 74 | length = 4; 75 | } 76 | 77 | printf("%s\"%s\":%s", comma, col->name, quote); 78 | 79 | for (int y = 0; y < length; y++) { 80 | switch (buffer[y]) { 81 | case '\n': 82 | putchar('\\'); 83 | putchar('n'); 84 | break; 85 | case '\t': 86 | putchar('\\'); 87 | putchar('t'); 88 | break; 89 | case '\r': 90 | putchar('\\'); 91 | putchar('r'); 92 | break; 93 | case '\f': 94 | putchar('\\'); 95 | putchar('f'); 96 | break; 97 | case '\b': 98 | putchar('\\'); 99 | putchar('b'); 100 | break; 101 | 102 | case '\\': 103 | case '"': 104 | putchar('\\'); 105 | // fall through 106 | default: 107 | putchar(buffer[y]); 108 | break; 109 | } 110 | } 111 | 112 | printf("%s", quote); 113 | 114 | comma = ","; 115 | } 116 | 117 | printf("}"); 118 | } 119 | 120 | static void json_start_rows(FILE* f, void* state) { 121 | struct state* st = state; 122 | 123 | fputs(st->start_extra, f); 124 | fputs("[\n", f); 125 | 126 | st->row_separator = ""; 127 | } 128 | 129 | static void json_end_rows(FILE* f, void* state) { 130 | struct state* st = state; 131 | 132 | fputs("\n]", f); 133 | fputs(st->end_extra, f); 134 | fputs("\n", f); 135 | } 136 | 137 | format_t json_format = { 138 | json_format_new, 139 | json_format_free, 140 | json_row, 141 | json_start_rows, 142 | json_end_rows 143 | }; 144 | -------------------------------------------------------------------------------- /format_json.h: -------------------------------------------------------------------------------- 1 | #ifndef FORMAT_JSON_H 2 | #define FORMAT_JSON_H 3 | 4 | #include "db2util.h" 5 | 6 | extern format_t json_format; 7 | 8 | #endif -------------------------------------------------------------------------------- /format_space.c: -------------------------------------------------------------------------------- 1 | #include 2 | 3 | #include "db2util.h" 4 | 5 | 6 | static void* space_format_new(void) { 7 | return NULL; 8 | } 9 | 10 | static void space_format_free(void* st) {} 11 | 12 | static void space_row(FILE* f, void* state, col_info_t* cols, int count) { 13 | const char* separator = ""; 14 | 15 | for(int i = 0; i < count; ++i) { 16 | printf("%s\"%.*s\"", separator, cols[i].ind, cols[i].data); 17 | separator = " "; 18 | } 19 | 20 | printf("\n"); 21 | } 22 | 23 | static void space_start_rows(FILE* f, void* state) {} 24 | 25 | static void space_end_rows(FILE* f, void* state) {} 26 | 27 | format_t space_format = { 28 | space_format_new, 29 | space_format_free, 30 | space_row, 31 | space_start_rows, 32 | space_end_rows 33 | }; 34 | -------------------------------------------------------------------------------- /format_space.h: -------------------------------------------------------------------------------- 1 | #ifndef FORMAT_SPACE_H 2 | #define FORMAT_SPACE_H 3 | 4 | #include "db2util.h" 5 | 6 | extern format_t space_format; 7 | 8 | #endif --------------------------------------------------------------------------------