resources/Editors/Editor.Roo.grid.Grid.bjs
[app.Builder.js] / src / Palete / RooDatabase.vala
1 /*
2  * Renderer for Roo Database code
3  * 
4  * - Concept - this code does the SQL queries
5  *   pulls data from information_schema (on mysql only at present..)
6  *   Sends it down the line to the Javascript code. to generate structures 
7  * 
8  */
9  
10  // should this be in palete...
11 namespace Palete {
12
13   
14     public class RooDatabase : Object 
15     {
16         public Project.Project project;
17
18                 public string DBTYPE;
19                 public string DBNAME;
20                  
21         public Gda.Connection cnc;
22         
23                 public RooDatabase.from_project (Project.Project project)
24         {
25             this.project = project;
26                         this.DBTYPE = this.project.get_string_member("DBTYPE");
27                         this.DBNAME = this.project.get_string_member("DBNAME");
28                         try {
29                                 
30                                         this.cnc = Gda.Connection.open_from_string (
31                                         this.DBTYPE,
32                                         "DB_NAME=" + this.DBNAME, 
33                                         "USERNAME=" + this.project.get_string_member("DBUSERNAME") + 
34                                         ";PASSWORD=" + this.project.get_string_member("DBPASSWORD"),
35                                         Gda.ConnectionOptions.NONE
36                                 );
37                         } catch(Gda.ConfigError e) {
38                                 print("%s\n", e.message);
39                                 this.cnc  = null;
40                                 this.DBTYPE = "";
41                         } catch(Gda.ConnectionError e) {
42                                 print("%s\n", e.message);
43                                 this.cnc  = null;
44                                 this.DBTYPE = "";
45                         }
46             
47         }
48        
49                 public RooDatabase.from_cfg (string dbtype, string dbname, string dbuser, string dbpass)
50                 {
51                         this.DBTYPE = dbtype;
52                         this.DBNAME = dbname;
53                         try {
54                                  this.cnc = Gda.Connection.open_from_string (
55                                         this.DBTYPE,
56                                         "DB_NAME=" + dbname, 
57                                         "USERNAME=" + dbuser + 
58                                         ";PASSWORD=" + dbpass,
59                                         Gda.ConnectionOptions.NONE
60                                 );
61                         } catch(Gda.ConfigError e) {
62                                 this.cnc  = null;
63                                 this.DBTYPE = "";
64                         } catch(Gda.ConnectionError e) {
65                                 this.cnc  = null;
66                                 this.DBTYPE = "";
67                         }
68
69             
70         }
71           
72         
73         public Json.Array readTables()
74         {
75                         
76                         if (this.DBTYPE == "PostgreSQL") {
77                                 
78                                 return this.fetchAll(this.cnc.execute_select_command( 
79                                         """select c.relname FROM pg_catalog.pg_class c 
80                                                 LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace 
81                                                 WHERE c.relkind IN ('r','') AND n.nspname NOT IN ('pg_catalog', 'pg_toast')
82                                                 AND pg_catalog.pg_table_is_visible(c.oid) 
83                                         """));
84                                 
85                         }
86                         if (this.DBTYPE == "MySQL") { 
87                                 return this.fetchAll(this.cnc.execute_select_command( "SHOW TABLES" ));
88                         }
89                         print("Read tables failed DBTYPE = %s\n", this.DBTYPE);
90                         return new Json.Array();
91                         
92                 }
93                 public Gee.ArrayList readTablesGee()
94                 {
95                         var ret = new Gee.ArrayList<string>();
96                         var ar = this.readTables();
97                         for(var i = 0; i < ar.get_length(); i++) {
98                                 ret.add(ar.get_string_element(i));
99                         }
100                         return ret;
101                         
102                 }
103                 
104                 public Json.Object readTable(string tablename) 
105                 {
106                         
107                         Json.Array res_ar;
108                         var res = new Json.Object();
109                         
110                         switch (this.DBTYPE ) {
111                                 case "PostgreSQL":
112                                 
113                                         res_ar =   this.fetchAll(this.cnc.execute_select_command( 
114                                         """
115                                         
116                                          SELECT 
117                                                 f.attnum AS number, 
118                                                 f.attname AS Field, 
119                                                 f.attnum, 
120                                                 CASE WHEN f.attnotnull = 't' THEN 'NO' ELSE 'YES' END AS isNull,  
121                                                 pg_catalog.format_type(f.atttypid,f.atttypmod) AS Type, 
122                                                 CASE WHEN p.contype = 'p' THEN 't' ELSE 'f' END AS primarykey, 
123                                                 CASE WHEN p.contype = 'u' THEN 't' ELSE 'f' END AS uniquekey, 
124                                                 CASE WHEN p.contype = 'f' THEN g.relname END AS foreignkey, 
125                                                 CASE WHEN p.contype = 'f' THEN p.confkey END AS foreignkey_fieldnum, 
126                                                 CASE WHEN p.contype = 'f' THEN g.relname END AS foreignkey, 
127                                                 CASE WHEN p.contype = 'f' THEN p.conkey END AS foreignkey_connnum, 
128                                                 CASE WHEN f.atthasdef = 't' THEN d.adsrc END AS default 
129                                                 FROM pg_attribute f JOIN pg_class c ON c.oid = f.attrelid 
130                                                                 JOIN pg_type t ON t.oid = f.atttypid 
131                                                                 LEFT JOIN pg_attrdef d ON d.adrelid = c.oid AND d.adnum = f.attnum 
132                                                                 LEFT JOIN pg_namespace n ON n.oid = c.relnamespace 
133                                                                 LEFT JOIN pg_constraint p ON p.conrelid = c.oid AND f.attnum = ANY ( p.conkey ) 
134                                                                 LEFT JOIN pg_class AS g ON p.confrelid = g.oid 
135                                                 WHERE c.relkind = 'r'::char AND n.nspname = 'public' 
136                                                 AND c.relname = '""" + tablename + """' AND f.attnum > 0 ORDER BY number;
137                                                         
138                                         """));
139                                         break;
140                                         
141                                 case  "MySQL":
142                                         res_ar = this.fetchAll(this.cnc.execute_select_command( "DESCRIBE " + tablename ));
143                                         break;
144                                 
145                                 default: 
146                                         return res;
147                                         break;
148                         }
149                         
150                         for (var i =0; i < res_ar.get_length(); i++) {
151                                 var el = res_ar.get_object_element(i);
152                                 res.set_object_member( el.get_string_member("Field"), el);
153                         }
154                         return res;
155                         
156                         
157                 }
158                 
159          
160                         
161                 
162                 
163                 public Json.Object readForeignKeys(string table)
164         { 
165                         
166                         
167                         var ret =   this.readTable(table);
168                         // technically we should use FK stuff in mysql, but for the momemnt use my hacky FK()
169                         if (this.DBTYPE != "MySQL") { 
170                                 return  ret;
171                         }
172                         
173                         var query = """
174                                 SELECT 
175                                 TABLE_COMMENT 
176                                 FROM
177                                 information_schema.TABLES
178                                 WHERE
179                                 TABLE_NAME = '""" + table + """'
180                                 AND
181                                 TABLE_SCHEMA = '""" + this.DBNAME + """'
182                         """;
183                         
184                         var jarr = this.fetchAll(this.cnc.execute_select_command( 
185                                         query
186                                         ));
187                         if (jarr.get_length() < 1) {
188                                 return  ret;
189                         }
190                         
191                         var contents = jarr.get_string_element(0);
192                         
193                          GLib.Regex exp = /FK\(([^\)]+)\)/;
194                          string str = "";
195                          try {
196                                 GLib.MatchInfo mi;
197                                 if ( exp.match (contents, 0, out mi) ) {
198                                         
199                                         str = mi.fetch(1);
200                                         print("match = %s", str);
201                                 }
202                         } catch (GLib.Error e) {
203                                 return  ret;
204                         }
205                         var ar = str.split("\n");
206                         for (var i = 0; i < ar.length; i++) {
207                                 var kv = ar[i].split("=");
208                                 if (!ret.has_member(kv[0].strip())) { 
209                                         continue;
210                                 }
211                                 var o = ret.get_object_member(kv[0].strip());
212                                 
213                                 //o.set_string_member("key", kv[0].strip());
214                                 var lr = kv[1].split(":");
215                                 o.set_string_member("relates_to_table", lr[0].strip());
216                                 o.set_string_member("relates_to_col", lr[1].strip());
217                                 o.set_object_member("relates_to_schema", this.readTable(lr[0].strip()));
218                                 //ret.set_object_member(kv[0].strip(),o);
219                                 
220                                 
221                         }
222                         return ret;
223                                  
224                 }
225         public Json.Array fetchAll(Gda.DataModel qnr)
226                 {
227                         var cols = new Gee.ArrayList<string>();
228                         
229                         for (var i =0;i < qnr.get_n_columns(); i++) {
230                                 cols.add(qnr.get_column_name(i));
231                         }
232                         //print(Json.stringify(cols, null,4));
233                         var iter = qnr.create_iter();
234                         var res = new Json.Array();
235                          //print("ROWS %d\n", qnr.get_n_rows());
236                         
237                         for (var r = 0; r < qnr.get_n_rows(); r++) {
238                                 
239                                 // single clo..
240                                 //print("GOT ROW");
241                                 //print("COLS  %d\n", cols.size);
242                                 if (cols.size == 1) {
243                                         var str = qnr.get_value_at(0,r).get_string();
244                                         //print("GOT %s\n",str);
245                                         res.add_string_element(qnr.get_value_at(0,r).get_string());
246                                         continue;
247                                 }
248                                 
249                                 var add = new Json.Object();
250                                 
251                                 for (var i = 0; i < cols.size; i++) { 
252                                         var n = cols.get(i);
253                                         var val = qnr.get_value_at(i,r);
254                                         var type = val.type().name();
255                                         //print("%s\n",type);
256                                         switch(type) {
257                                                 case "GdaBinary":
258                                                 case "GdaBlob":
259                                                         add.set_string_member(n, "?? big string ??");
260                                                         break;
261                                                         
262                                                 case  "GdaNull":
263                                                         add.set_null_member(n);
264                                                         break;
265                                                 
266                                                 default:
267                                                         add.set_string_member(n, val.get_string());
268                                                         break;
269                                         }
270                                         
271                                 }
272                                 
273                                 res.add_object_element(add);
274                                 
275                         }
276                         return res;
277
278                 }
279                 
280                 
281                 
282         }
283         
284         
285 }
286 // valac --pkg libgda-5.0 --pkg gee-1.0 --pkg json-glib-1.0  --pkg libxml-2.0   RooDatabase.vala  -o /tmp/rdtest
287 /*
288  void main() {
289      var x = new JsRender.RooDatabase.from_cfg("MySQL", "hydra", "root", "");
290     // var res = x.readTables();
291     //var res= x.readTable("Person");
292     var res= x.readForeignKeys("Person");
293     
294         var  generator = new Json.Generator ();
295     var  root = new Json.Node(Json.NodeType.OBJECT);
296     root.init_object(res);
297     generator.set_root (root);
298     
299             generator.pretty = true;
300             generator.indent = 4;
301     
302
303     print("%s\n", generator.to_data (null));
304  }
305 */