table.py 32 KB

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