table.py 34 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966
  1. # -*- coding: utf-8 -*-
  2. """
  3. Created on Wed Aug 8 15:29:21 2012
  4. @author: pietro
  5. """
  6. import ctypes
  7. import numpy as np
  8. try:
  9. from collections import OrderedDict
  10. except:
  11. from grass.pygrass.orderdict import OrderedDict
  12. import grass.lib.vector as libvect
  13. from grass.pygrass.gis import Mapset
  14. from grass.pygrass.errors import DBError
  15. from grass.script.db import db_table_in_vector
  16. from grass.script.core import warning
  17. import sys
  18. import sql
  19. import os
  20. DRIVERS = ('sqlite', 'pg')
  21. def get_path(path):
  22. """Return the full path to the database; replacing environment variable
  23. with real values ::
  24. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  25. >>> new_path = get_path(path)
  26. >>> from grass.script.core import gisenv
  27. >>> import os
  28. >>> new_path2 = os.path.join(gisenv()['GISDBASE'], gisenv()['LOCATION_NAME'],
  29. ... gisenv()['MAPSET'], 'sqlite', 'sqlite.db')
  30. >>> new_path == new_path2
  31. True
  32. """
  33. if "$" not in path:
  34. return path
  35. else:
  36. mapset = Mapset()
  37. path = path.replace('$GISDBASE', mapset.gisdbase)
  38. path = path.replace('$LOCATION_NAME', mapset.location)
  39. path = path.replace('$MAPSET', mapset.name)
  40. return path
  41. class Filters(object):
  42. """Help user to build a simple sql query. ::
  43. >>> filter = Filters('table')
  44. >>> filter.get_sql()
  45. 'SELECT * FROM table;'
  46. >>> filter.where("area<10000").get_sql()
  47. 'SELECT * FROM table WHERE area<10000;'
  48. >>> filter.select("cat", "area").get_sql()
  49. 'SELECT cat, area FROM table WHERE area<10000;'
  50. >>> filter.order_by("area").limit(10).get_sql()
  51. 'SELECT cat, area FROM table WHERE area<10000 ORDER BY area LIMIT 10;'
  52. ..
  53. """
  54. def __init__(self, tname):
  55. self.tname = tname
  56. self._select = None
  57. self._where = None
  58. self._orderby = None
  59. self._limit = None
  60. self._groupby = None
  61. def __repr__(self):
  62. return "Filters(%r)" % self.get_sql()
  63. def select(self, *args):
  64. """Create the select query"""
  65. cols = ', '.join(args) if args else '*'
  66. select = sql.SELECT[:-1]
  67. self._select = select.format(cols=cols, tname=self.tname)
  68. return self
  69. def where(self, condition):
  70. """Create the where condition"""
  71. self._where = 'WHERE {condition}'.format(condition=condition)
  72. return self
  73. def order_by(self, orderby):
  74. """Create the order by condition"""
  75. if not isinstance(orderby, str):
  76. orderby = ', '.join(orderby)
  77. self._orderby = 'ORDER BY {orderby}'.format(orderby=orderby)
  78. return self
  79. def limit(self, number):
  80. """Create the limit condition"""
  81. if not isinstance(number, int):
  82. raise ValueError("Must be an integer.")
  83. else:
  84. self._limit = 'LIMIT {number}'.format(number=number)
  85. return self
  86. def group_by(self, groupby):
  87. """Create the group by condition"""
  88. if not isinstance(groupby, str):
  89. groupby = ', '.join(groupby)
  90. self._groupby = 'GROUP BY {groupby}'.format(groupby=groupby)
  91. return self
  92. def get_sql(self):
  93. """Return the SQL query"""
  94. sql_list = list()
  95. if self._select is None:
  96. self.select()
  97. sql_list.append(self._select)
  98. if self._where is not None:
  99. sql_list.append(self._where)
  100. if self._groupby is not None:
  101. sql_list.append(self._groupby)
  102. if self._orderby is not None:
  103. sql_list.append(self._orderby)
  104. if self._limit is not None:
  105. sql_list.append(self._limit)
  106. return "%s;" % ' '.join(sql_list)
  107. def reset(self):
  108. """Clean internal variables"""
  109. self._select = None
  110. self._where = None
  111. self._orderby = None
  112. self._limit = None
  113. self._groupby = None
  114. class Columns(object):
  115. """Object to work with columns table.
  116. It is possible to instantiate a Columns object given the table name and
  117. the database connection.
  118. For a sqlite table: ::
  119. >>> import sqlite3
  120. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  121. >>> cols_sqlite = Columns('census',
  122. ... sqlite3.connect(get_path(path)))
  123. >>> cols_sqlite.tname
  124. 'census'
  125. For a postgreSQL table: ::
  126. >>> import psycopg2 as pg #doctest: +SKIP
  127. >>> cols_pg = Columns('boundary_municp_pg',
  128. ... pg.connect('host=localhost dbname=grassdb')) #doctest: +SKIP
  129. >>> cols_pg.tname #doctest: +SKIP
  130. 'boundary_municp_pg' #doctest: +SKIP
  131. ..
  132. """
  133. def __init__(self, tname, connection, key='cat'):
  134. self.tname = tname
  135. self.conn = connection
  136. self.key = key
  137. self.odict = None
  138. self.update_odict()
  139. def __contains__(self, item):
  140. return item in self.names()
  141. def __repr__(self):
  142. return "Columns(%r)" % self.items()
  143. def __getitem__(self, key):
  144. return self.odict[key]
  145. def __setitem__(self, name, new_type):
  146. self.cast(name, new_type)
  147. self.update_odict(self)
  148. def __iter__(self):
  149. return self.odict.__iter__()
  150. def __len__(self):
  151. return self.odict.__len__()
  152. def __eq__(self, obj):
  153. return obj.tname == self.tname and obj.odict == self.odict
  154. def is_pg(self):
  155. """Return True if is a psycopg connection. ::
  156. >>> import sqlite3
  157. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  158. >>> cols_sqlite = Columns('census',
  159. ... sqlite3.connect(get_path(path)))
  160. >>> cols_sqlite.is_pg()
  161. False
  162. >>> import psycopg2 as pg #doctest: +SKIP
  163. >>> cols_pg = Columns('boundary_municp_pg',
  164. ... pg.connect('host=localhost dbname=grassdb')) #doctest: +SKIP
  165. >>> cols_pg.is_pg() #doctest: +SKIP
  166. True
  167. ..
  168. """
  169. return hasattr(self.conn, 'xid')
  170. def update_odict(self):
  171. """Read columns name and types from table and update the odict
  172. attribute.
  173. """
  174. if self.is_pg():
  175. # is a postgres connection
  176. cur = self.conn.cursor()
  177. cur.execute("SELECT oid,typname FROM pg_type")
  178. diz = dict(cur.fetchall())
  179. odict = OrderedDict()
  180. import psycopg2 as pg
  181. try:
  182. cur.execute(sql.SELECT.format(cols='*', tname=self.tname))
  183. descr = cur.description
  184. for column in descr:
  185. name, ctype = column[:2]
  186. odict[name] = diz[ctype]
  187. except pg.ProgrammingError:
  188. pass
  189. self.odict = odict
  190. else:
  191. # is a sqlite connection
  192. cur = self.conn.cursor()
  193. cur.execute(sql.PRAGMA.format(tname=self.tname))
  194. descr = cur.fetchall()
  195. odict = OrderedDict()
  196. for column in descr:
  197. name, ctype = column[1:3]
  198. odict[name] = ctype
  199. self.odict = odict
  200. values = ','.join(['?', ] * self.__len__())
  201. kv = ','.join(['%s=?' % k for k in self.odict.keys()])
  202. where = "%s=?" % self.key
  203. self.insert_str = sql.INSERT.format(tname=self.tname, values=values)
  204. self.update_str = sql.UPDATE_WHERE.format(tname=self.tname,
  205. values=kv, condition=where)
  206. def sql_descr(self, remove=None):
  207. """Return a string with description of columns.
  208. Remove it is used to remove a columns.::
  209. >>> import sqlite3
  210. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  211. >>> cols_sqlite = Columns('census',
  212. ... sqlite3.connect(get_path(path)))
  213. >>> cols_sqlite.sql_descr() # doctest: +ELLIPSIS
  214. u'cat INTEGER, OBJECTID INTEGER, AREA DOUBLE PRECISION, ...'
  215. >>> import psycopg2 as pg # doctest: +SKIP
  216. >>> cols_pg = Columns('boundary_municp_pg',
  217. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  218. >>> cols_pg.sql_descr() # doctest: +ELLIPSIS +SKIP
  219. 'cat int4, objectid int4, area float8, perimeter float8, ...'
  220. """
  221. if remove:
  222. return ', '.join(['%s %s' % (key, val) for key, val in self.items()
  223. if key != remove])
  224. else:
  225. return ', '.join(['%s %s' % (key, val)
  226. for key, val in self.items()])
  227. def types(self):
  228. """Return a list with the column types. ::
  229. >>> import sqlite3
  230. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  231. >>> cols_sqlite = Columns('census',
  232. ... sqlite3.connect(get_path(path)))
  233. >>> cols_sqlite.types() # doctest: +ELLIPSIS
  234. [u'INTEGER', u'INTEGER', ...]
  235. >>> import psycopg2 as pg # doctest: +SKIP
  236. >>> cols_pg = Columns('boundary_municp_pg',
  237. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  238. >>> cols_pg.types() # doctest: +ELLIPSIS +SKIP
  239. ['int4', 'int4', 'float8', 'float8', 'float8', ...]
  240. ..
  241. """
  242. return self.odict.values()
  243. def names(self, remove=None, unicod=True):
  244. """Return a list with the column names.
  245. Remove it is used to remove a columns.::
  246. >>> import sqlite3
  247. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  248. >>> cols_sqlite = Columns('census',
  249. ... sqlite3.connect(get_path(path)))
  250. >>> cols_sqlite.names() # doctest: +ELLIPSIS
  251. [u'cat', u'OBJECTID', u'AREA', u'PERIMETER', ...]
  252. >>> import psycopg2 as pg # doctest: +SKIP
  253. >>> cols_pg = Columns('boundary_municp_pg', # doctest: +SKIP
  254. ... pg.connect('host=localhost dbname=grassdb'))
  255. >>> cols_pg.names() # doctest: +ELLIPSIS +SKIP
  256. ['cat', 'objectid', 'area', 'perimeter', ...]
  257. ..
  258. """
  259. if remove:
  260. nams = self.odict.keys()
  261. nams.remove(remove)
  262. else:
  263. nams = self.odict.keys()
  264. if unicod:
  265. return nams
  266. else:
  267. return [str(name) for name in nams]
  268. def items(self):
  269. """Return a list of tuple with column name and column type. ::
  270. >>> import sqlite3
  271. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  272. >>> cols_sqlite = Columns('census',
  273. ... sqlite3.connect(get_path(path)))
  274. >>> cols_sqlite.items() # doctest: +ELLIPSIS
  275. [(u'cat', u'INTEGER'), ...]
  276. >>> import psycopg2 as pg # doctest: +SKIP
  277. >>> cols_pg = Columns('boundary_municp_pg',
  278. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  279. >>> cols_pg.items() # doctest: +ELLIPSIS +SKIP
  280. [('cat', 'int4'), ('objectid', 'int4'), ('area', 'float8'), ...]
  281. ..
  282. """
  283. return self.odict.items()
  284. def add(self, col_name, col_type):
  285. """Add a new column to the table. ::
  286. >>> import sqlite3
  287. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  288. >>> from grass.pygrass.functions import copy, remove
  289. >>> copy('census','mycensus','vect')
  290. >>> cols_sqlite = Columns('mycensus',
  291. ... sqlite3.connect(get_path(path)))
  292. >>> cols_sqlite.add('n_pizza', 'INT')
  293. >>> 'n_pizza' in cols_sqlite
  294. True
  295. >>> import psycopg2 as pg # doctest: +SKIP
  296. >>> cols_pg = Columns('boundary_municp_pg',
  297. ... pg.connect('host=localhost dbname=grassdb')) #doctest: +SKIP
  298. >>> cols_pg.add('n_pizza', 'INT') # doctest: +SKIP
  299. >>> 'n_pizza' in cols_pg # doctest: +SKIP
  300. True
  301. >>> remove('mycensus', 'vect')
  302. ..
  303. """
  304. valid_type = ('DOUBLE PRECISION', 'INT', 'DATE')
  305. if 'VARCHAR' in col_type or col_type.upper() not in valid_type:
  306. str_err = "Type is not supported, supported types are: %s"
  307. raise TypeError(str_err % ", ".join(valid_type))
  308. cur = self.conn.cursor()
  309. cur.execute(sql.ADD_COL.format(tname=self.tname,
  310. cname=col_name,
  311. ctype=col_type))
  312. self.conn.commit()
  313. cur.close()
  314. self.update_odict()
  315. def rename(self, old_name, new_name):
  316. """Rename a column of the table. ::
  317. >>> import sqlite3
  318. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  319. >>> from grass.pygrass.functions import copy, remove
  320. >>> copy('census','mycensus','vect')
  321. >>> cols_sqlite = Columns('mycensus',
  322. ... sqlite3.connect(get_path(path)))
  323. >>> cols_sqlite.add('n_pizza', 'INT')
  324. >>> 'n_pizza' in cols_sqlite
  325. True
  326. >>> cols_sqlite.rename('n_pizza', 'n_pizzas') # doctest: +ELLIPSIS
  327. >>> 'n_pizza' in cols_sqlite
  328. False
  329. >>> 'n_pizzas' in cols_sqlite
  330. True
  331. >>> import psycopg2 as pg # doctest: +SKIP
  332. >>> cols_pg = Columns('boundary_municp_pg',
  333. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  334. >>> cols_pg.rename('n_pizza', 'n_pizzas') # doctest: +SKIP
  335. >>> 'n_pizza' in cols_pg # doctest: +SKIP
  336. False
  337. >>> 'n_pizzas' in cols_pg # doctest: +SKIP
  338. True
  339. >>> remove('mycensus', 'vect')
  340. ..
  341. """
  342. cur = self.conn.cursor()
  343. if self.is_pg():
  344. cur.execute(sql.RENAME_COL.format(tname=self.tname,
  345. old_name=old_name,
  346. new_name=new_name))
  347. self.conn.commit()
  348. cur.close()
  349. self.update_odict()
  350. else:
  351. cur.execute(sql.ADD_COL.format(tname=self.tname,
  352. cname=new_name,
  353. ctype=str(self.odict[old_name])))
  354. cur.execute(sql.UPDATE.format(tname=self.tname,
  355. new_col=new_name,
  356. old_col=old_name))
  357. self.conn.commit()
  358. cur.close()
  359. self.update_odict()
  360. self.drop(old_name)
  361. def cast(self, col_name, new_type):
  362. """Change the column type. ::
  363. >>> import sqlite3
  364. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  365. >>> from grass.pygrass.functions import copy, remove
  366. >>> copy('census','mycensus','vect')
  367. >>> cols_sqlite = Columns('mycensus',
  368. ... sqlite3.connect(get_path(path)))
  369. >>> cols_sqlite.add('n_pizzas', 'INT')
  370. >>> cols_sqlite.cast('n_pizzas', 'float8') # doctest: +ELLIPSIS
  371. Traceback (most recent call last):
  372. ...
  373. DBError: 'SQLite does not support to cast columns.'
  374. >>> import psycopg2 as pg # doctest: +SKIP
  375. >>> cols_pg = Columns('boundary_municp_pg',
  376. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  377. >>> cols_pg.cast('n_pizzas', 'float8') # doctest: +SKIP
  378. >>> cols_pg['n_pizzas'] # doctest: +SKIP
  379. 'float8'
  380. >>> remove('mycensus', 'vect')
  381. .. warning ::
  382. It is not possible to cast a column with sqlite
  383. ..
  384. """
  385. if self.is_pg():
  386. cur = self.conn.cursor()
  387. cur.execute(sql.CAST_COL.format(tname=self.tname, col=col_name,
  388. ctype=new_type))
  389. self.conn.commit()
  390. cur.close()
  391. self.update_odict()
  392. else:
  393. # sqlite does not support rename columns:
  394. raise DBError('SQLite does not support to cast columns.')
  395. def drop(self, col_name):
  396. """Drop a column from the table. ::
  397. >>> import sqlite3
  398. >>> path = '$GISDBASE/$LOCATION_NAME/$MAPSET/sqlite/sqlite.db'
  399. >>> from grass.pygrass.functions import copy, remove
  400. >>> copy('census','mycensus','vect')
  401. >>> cols_sqlite = Columns('mycensus',
  402. ... sqlite3.connect(get_path(path)))
  403. >>> cols_sqlite.drop('CHILD') # doctest: +ELLIPSIS
  404. >>> 'CHILD' in cols_sqlite
  405. False
  406. >>> import psycopg2 as pg # doctest: +SKIP
  407. >>> cols_pg = Columns('boundary_municp_pg',
  408. ... pg.connect('host=localhost dbname=grassdb')) # doctest: +SKIP
  409. >>> cols_pg.drop('CHILD') # doctest: +SKIP
  410. >>> 'CHILD' in cols_pg # doctest: +SKIP
  411. False
  412. >>> remove('mycensus','vect')
  413. ..
  414. """
  415. cur = self.conn.cursor()
  416. if self.is_pg():
  417. cur.execute(sql.DROP_COL.format(tname=self.tname,
  418. cname=col_name))
  419. else:
  420. desc = str(self.sql_descr(remove=col_name))
  421. names = ', '.join(self.names(remove=col_name, unicod=False))
  422. queries = sql.DROP_COL_SQLITE.format(tname=self.tname,
  423. keycol=self.key,
  424. coldef=desc,
  425. colnames=names).split('\n')
  426. for query in queries:
  427. cur.execute(query)
  428. self.conn.commit()
  429. cur.close()
  430. self.update_odict()
  431. class Link(object):
  432. """Define a Link between vector map and the attributes table.
  433. It is possible to define a Link object or given all the information
  434. (layer, name, table name, key, database, driver): ::
  435. >>> link = Link(1, 'link0', 'census', 'cat',
  436. ... '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db', 'sqlite')
  437. >>> link.number # doctest: +SKIP
  438. 1
  439. >>> link.name
  440. 'link0'
  441. >>> link.table_name
  442. 'census'
  443. >>> link.key
  444. 'cat'
  445. >>> link.database
  446. '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  447. >>> link.driver
  448. 'sqlite'
  449. >>> link
  450. Link(1, link0, sqlite)
  451. It is possible to change parameters with: ::
  452. >>> link.driver = 'pg' # doctest: +SKIP
  453. >>> link.driver # doctest: +SKIP
  454. 'pg'
  455. >>> link.driver = 'postgres' # doctest: +ELLIPSIS +SKIP
  456. Traceback (most recent call last):
  457. ...
  458. TypeError: Driver not supported, use: sqlite, pg.
  459. >>> link.driver # doctest: +SKIP
  460. 'pg'
  461. >>> link.number = 0 # doctest: +ELLIPSIS +SKIP
  462. Traceback (most recent call last):
  463. ...
  464. TypeError: Number must be positive and greater than 0.
  465. Or given a c_fieldinfo object that is a ctypes pointer to the field_info C
  466. struct. ::
  467. >>> link = Link(c_fieldinfo = ctypes.pointer(libvect.field_info()))
  468. ..
  469. """
  470. def _get_layer(self):
  471. return self.c_fieldinfo.contents.number
  472. def _set_layer(self, number):
  473. if number <= 0:
  474. raise TypeError("Number must be positive and greater than 0.")
  475. self.c_fieldinfo.contents.number = number
  476. layer = property(fget=_get_layer, fset=_set_layer)
  477. def _get_name(self):
  478. return self.c_fieldinfo.contents.name
  479. def _set_name(self, name):
  480. self.c_fieldinfo.contents.name = name
  481. name = property(fget=_get_name, fset=_set_name)
  482. def _get_table(self):
  483. return self.c_fieldinfo.contents.table
  484. def _set_table(self, new_name):
  485. self.c_fieldinfo.contents.table = new_name
  486. table_name = property(fget=_get_table, fset=_set_table)
  487. def _get_key(self):
  488. return self.c_fieldinfo.contents.key
  489. def _set_key(self, key):
  490. self.c_fieldinfo.contents.key = key
  491. key = property(fget=_get_key, fset=_set_key)
  492. def _get_database(self):
  493. return self.c_fieldinfo.contents.database
  494. def _set_database(self, database):
  495. self.c_fieldinfo.contents.database = database
  496. database = property(fget=_get_database, fset=_set_database)
  497. def _get_driver(self):
  498. return self.c_fieldinfo.contents.driver
  499. def _set_driver(self, driver):
  500. if driver not in ('sqlite', 'pg'):
  501. str_err = "Driver not supported, use: %s." % ", ".join(DRIVERS)
  502. raise TypeError(str_err)
  503. self.c_fieldinfo.contents.driver = driver
  504. driver = property(fget=_get_driver, fset=_set_driver)
  505. def __init__(self, layer=1, name=None, table=None, key='cat',
  506. database='$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db',
  507. driver='sqlite', c_fieldinfo=None):
  508. if c_fieldinfo is not None:
  509. self.c_fieldinfo = c_fieldinfo
  510. else:
  511. self.c_fieldinfo = ctypes.pointer(libvect.field_info())
  512. self.layer = layer
  513. self.name = name
  514. self.table_name = table
  515. self.key = key
  516. self.database = database
  517. self.driver = driver
  518. def __repr__(self):
  519. return "Link(%d, %s, %s)" % (self.layer, self.name, self.driver)
  520. def connection(self):
  521. """Return a connection object. ::
  522. >>> link = Link(1, 'link0', 'census', 'cat',
  523. ... '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db',
  524. ... 'sqlite')
  525. >>> conn = link.connection()
  526. >>> cur = conn.cursor()
  527. >>> cur.execute("SELECT cat,TOTAL_POP,PERIMETER FROM %s" %
  528. ... link.table_name) # doctest: +ELLIPSIS
  529. <sqlite3.Cursor object at ...>
  530. >>> cur.fetchone()
  531. (1, 44, 757.669)
  532. >>> cur.close()
  533. >>> conn.close()
  534. ...
  535. """
  536. if self.driver == 'sqlite':
  537. import sqlite3
  538. # Numpy is using some custom integer data types to efficiently
  539. # pack data into memory. Since these types aren't familiar to
  540. # sqlite, you'll have to tell it about how to handle them.
  541. for t in (np.int8, np.int16, np.int32, np.int64, np.uint8,
  542. np.uint16, np.uint32, np.uint64):
  543. sqlite3.register_adapter(t, long)
  544. dbpath = get_path(self.database)
  545. dbdirpath = os.path.split(dbpath)[0]
  546. if not os.path.exists(dbdirpath):
  547. os.mkdir(dbdirpath)
  548. return sqlite3.connect(dbpath)
  549. elif self.driver == 'pg':
  550. try:
  551. import psycopg2
  552. db = ' '.join(self.database.split(','))
  553. return psycopg2.connect(db)
  554. except ImportError:
  555. er = "You need to install psycopg2 to connect with this table."
  556. raise ImportError(er)
  557. else:
  558. str_err = "Driver is not supported yet, pleas use: sqlite or pg"
  559. raise TypeError(str_err)
  560. def table(self):
  561. """Return a Table object. ::
  562. >>> link = Link(1, 'link0', 'census', 'cat',
  563. ... '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db',
  564. ... 'sqlite')
  565. >>> table = link.table()
  566. >>> table.filters.select('cat', 'TOTAL_POP', 'PERIMETER')
  567. Filters('SELECT cat, TOTAL_POP, PERIMETER FROM census;')
  568. >>> cur = table.execute()
  569. >>> cur.fetchone()
  570. (1, 44, 757.669)
  571. >>> cur.close()
  572. ..
  573. """
  574. return Table(self.table_name, self.connection(), self.key)
  575. def info(self):
  576. """Print information of the link. ::
  577. >>> link = Link(1, 'link0', 'census', 'cat',
  578. ... '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db',
  579. ... 'sqlite')
  580. >>> link.info()
  581. layer: 1
  582. name: link0
  583. table: census
  584. key: cat
  585. database: $GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db
  586. driver: sqlite
  587. ..
  588. """
  589. print "layer: ", self.layer
  590. print "name: ", self.name
  591. print "table: ", self.table_name
  592. print "key: ", self.key
  593. print "database: ", self.database
  594. print "driver: ", self.driver
  595. class DBlinks(object):
  596. """Interface containing link to the table DB. ::
  597. >>> from grass.pygrass.vector import VectorTopo
  598. >>> cens = VectorTopo('census')
  599. >>> cens.open()
  600. >>> dblinks = DBlinks(cens.c_mapinfo)
  601. >>> dblinks
  602. DBlinks([Link(1, census, sqlite)])
  603. >>> dblinks[0]
  604. Link(1, census, sqlite)
  605. >>> dblinks['census']
  606. Link(1, census, sqlite)
  607. ..
  608. """
  609. def __init__(self, c_mapinfo):
  610. self.c_mapinfo = c_mapinfo
  611. def __len__(self):
  612. return self.num_dblinks()
  613. def __iter__(self):
  614. return (self.by_index(i)
  615. for i in xrange(self.num_dblinks()))
  616. def __getitem__(self, item):
  617. """
  618. """
  619. if isinstance(item, int):
  620. return self.by_index(item)
  621. else:
  622. return self.by_name(item)
  623. def __repr__(self):
  624. return "DBlinks(%r)" % [link for link in self.__iter__()]
  625. def by_index(self, indx):
  626. c_fieldinfo = libvect.Vect_get_dblink(self.c_mapinfo, indx)
  627. return Link(c_fieldinfo=c_fieldinfo)
  628. def by_layer(self, layer):
  629. c_fieldinfo = libvect.Vect_get_field(self.c_mapinfo, layer)
  630. return Link(c_fieldinfo=c_fieldinfo)
  631. def by_name(self, name):
  632. c_fieldinfo = libvect.Vect_get_field_by_name(self.c_mapinfo, name)
  633. return Link(c_fieldinfo=c_fieldinfo)
  634. def num_dblinks(self):
  635. return libvect.Vect_get_num_dblinks(self.c_mapinfo)
  636. def add(self, link):
  637. """Add a new link.
  638. Need to open vector map in write mode::
  639. >>> from grass.pygrass.vector import VectorTopo
  640. >>> municip = VectorTopo('census')
  641. >>> municip.open()
  642. >>> dblinks = DBlinks(municip.c_mapinfo)
  643. >>> dblinks
  644. DBlinks([Link(1, census, sqlite)])
  645. >>> link = Link(2, 'pg_link', 'boundary_municp_pg', 'cat',
  646. ... 'host=localhost dbname=grassdb', 'pg') # doctest: +SKIP
  647. >>> dblinks.add(link) # doctest: +SKIP
  648. >>> dblinks # doctest: +SKIP
  649. DBlinks([Link(1, boundary_municp, sqlite)])
  650. ..
  651. """
  652. #TODO: check if open in write mode or not.
  653. libvect.Vect_map_add_dblink(self.c_mapinfo,
  654. link.layer, link.name, link.table_name,
  655. link.key, link.database, link.driver)
  656. def remove(self, key, force=False):
  657. """Remove a link. If force set to true remove also the table ::
  658. >>> from grass.pygrass.vector import VectorTopo
  659. >>> municip = VectorTopo('census')
  660. >>> municip.open()
  661. >>> dblinks = DBlinks(municip.c_mapinfo)
  662. >>> dblinks
  663. DBlinks([Link(1, census, sqlite)])
  664. >>> dblinks.remove('pg_link') # doctest: +SKIP
  665. >>> dblinks # need to open vector map in write mode
  666. DBlinks([Link(1, census, sqlite)])
  667. ..
  668. """
  669. if force:
  670. link = self.by_name(key)
  671. table = link.table()
  672. table.drop(force=force)
  673. if isinstance(key, str):
  674. key = self.from_name_to_num(key)
  675. libvect.Vect_map_del_dblink(self.c_mapinfo, key)
  676. def from_name_to_num(self, name):
  677. """
  678. Vect_get_field_number
  679. """
  680. return libvect.Vect_get_field_number(self.c_mapinfo, name)
  681. class Table(object):
  682. """::
  683. >>> import sqlite3
  684. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  685. >>> tab_sqlite = Table(name='census',
  686. ... connection=sqlite3.connect(get_path(path)))
  687. >>> tab_sqlite.name
  688. 'census'
  689. >>> import psycopg2 # doctest: +SKIP
  690. >>> tab_pg = Table('boundary_municp_pg',
  691. ... psycopg2.connect('host=localhost dbname=grassdb',
  692. ... 'pg')) # doctest: +SKIP
  693. >>> tab_pg.columns # doctest: +ELLIPSIS +SKIP
  694. Columns([('cat', 'int4'), ...])
  695. ..
  696. """
  697. def _get_name(self):
  698. """Private method to return the name of table"""
  699. return self._name
  700. def _set_name(self, new_name):
  701. """Private method to set the name of table"""
  702. old_name = self._name
  703. cur = self.conn.cursor()
  704. cur.execute(sql.RENAME_TAB.format(old_name=old_name,
  705. new_name=new_name))
  706. cur.commit()
  707. cur.close()
  708. name = property(fget=_get_name, fset=_set_name)
  709. def __init__(self, name, connection, key='cat'):
  710. self._name = name
  711. self.conn = connection
  712. self.key = key
  713. self.columns = Columns(self.name,
  714. self.conn,
  715. self.key)
  716. self.filters = Filters(self.name)
  717. def __repr__(self):
  718. """::
  719. >>> import sqlite3
  720. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  721. >>> tab_sqlite = Table(name='census',
  722. ... connection=sqlite3.connect(get_path(path)))
  723. >>> tab_sqlite
  724. Table('census')
  725. ..
  726. """
  727. return "Table(%r)" % (self.name)
  728. def __iter__(self):
  729. cur = self.execute()
  730. return (cur.fetchone() for _ in xrange(self.__len__()))
  731. def __len__(self):
  732. """Return the number of rows"""
  733. return self.n_rows()
  734. def drop(self, name=None, force=False):
  735. """Private method to drop table from database"""
  736. if name:
  737. name = name
  738. else:
  739. name = self.name
  740. used = db_table_in_vector(name)
  741. if len(used) > 0:
  742. warning(_("Deleting table <%s> which is attached to following map(s):") % name)
  743. for vect in used:
  744. warning("%s" % vect)
  745. if not force:
  746. warning(_("You must use the force flag to actually remove it. Exiting."))
  747. sys.exit(0)
  748. else:
  749. cur = self.conn.cursor()
  750. cur.execute(sql.DROP_TAB.format(tname=name))
  751. else:
  752. cur = self.conn.cursor()
  753. cur.execute(sql.DROP_TAB.format(tname=name))
  754. def n_rows(self):
  755. """Return the number of rows
  756. >>> import sqlite3
  757. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  758. >>> tab_sqlite = Table(name='census',
  759. ... connection=sqlite3.connect(get_path(path)))
  760. >>> tab_sqlite.n_rows()
  761. 2537
  762. """
  763. cur = self.conn.cursor()
  764. cur.execute(sql.SELECT.format(cols='Count(*)', tname=self.name))
  765. number = cur.fetchone()[0]
  766. cur.close()
  767. return number
  768. def execute(self, sql_code=None):
  769. """Execute SQL code from a given string or build with filters and
  770. return a cursor object. ::
  771. >>> import sqlite3
  772. >>> path = '$GISDBASE/$LOCATION_NAME/PERMANENT/sqlite/sqlite.db'
  773. >>> tab_sqlite = Table(name='census',
  774. ... connection=sqlite3.connect(get_path(path)))
  775. >>> tab_sqlite.filters.select('cat', 'TOTAL_POP').order_by('AREA')
  776. Filters('SELECT cat, TOTAL_POP FROM census ORDER BY AREA;')
  777. >>> cur = tab_sqlite.execute()
  778. >>> cur.fetchone()
  779. (1856, 0)
  780. ..
  781. """
  782. try:
  783. sqlc = sql_code if sql_code else self.filters.get_sql()
  784. cur = self.conn.cursor()
  785. #if hasattr(self.cur, 'executescript'):
  786. # return cur.executescript(sqlc)
  787. return cur.execute(sqlc)
  788. except:
  789. raise ValueError("The SQL is not correct:\n%r" % sqlc)
  790. def insert(self, values, many=False):
  791. """Insert a new row"""
  792. cur = self.conn.cursor()
  793. if many:
  794. return cur.executemany(self.columns.insert_str, values)
  795. return cur.execute(self.columns.insert_str, values)
  796. def update(self, key, values):
  797. """Update a column for each row"""
  798. cur = self.conn.cursor()
  799. vals = list(values)
  800. vals.append(key)
  801. return cur.execute(self.columns.update_str, vals)
  802. def create(self, cols, name=None):
  803. """Create a new table"""
  804. cur = self.conn.cursor()
  805. coldef = ',\n'.join(['%s %s' % col for col in cols])
  806. if name:
  807. newname = name
  808. else:
  809. newname = self.name
  810. cur.execute(sql.CREATE_TAB.format(tname=newname, coldef=coldef))
  811. self.conn.commit()
  812. cur.close()
  813. self.columns.update_odict()