table.py 33 KB

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