Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

SqlDatabase module

  • Loading branch information...
commit a58225034c1272452ccb9ebfc9b66d9a3701296d 1 parent 84d76c6
octavian-sima authored
View
300 sql_database/Database.cpp
@@ -0,0 +1,300 @@
+/*
+ * File: Database.cpp
+ * Author: Elena Holobiuc
+ */
+
+#include <stdio.h>
+#include <string.h>
+#include <iostream>
+#include <mysql/mysql.h>
+#include <stdlib.h>
+
+#include "Database.h"
+
+Database::Database() {
+
+}
+
+Database::~Database() {
+
+ // close current connection ( if any )
+ if (this->connection_) {
+ mysql_close(this->connection_);
+ }
+}
+
+void Database::connect() {
+
+ // connect to mysql Database
+ mysql_init(&this->mysql_);
+
+ this->connection_ = mysql_real_connect(&this->mysql_,
+ HOST,
+ USER,
+ PASSWORD,
+ DATABASE_NAME,
+ 0,
+ NULL,
+ 0
+ );
+
+ // test successful connection
+ if ( this->connection_ == NULL ) {
+ fprintf(stderr, "[Database] Error while connecting to mysql database!\n");
+ exit(0);
+ }
+
+}
+
+void Database::disconnect() {
+
+ // close current connection
+ mysql_close(this->connection_);
+}
+
+int Database::getPersonId(char* fname, char* lname) {
+
+ // mysql query result
+ MYSQL_RES *result;
+ MYSQL_ROW row;
+ char* queryString = (char*)malloc(100*sizeof(char));
+ int queryErrno;
+ int id = -1;
+
+ // prepare query
+ sprintf(queryString,"CALL GetPersonID('%s','%s',@idToString)",fname,lname);
+
+ // run query
+ queryErrno = mysql_query(this->connection_, queryString);
+ // check for query error
+ if (queryErrno !=0) {
+ fprintf(stderr, "[Database] Error calling mysql function: %s\n",
+ mysql_error(this->connection_));
+ return id;
+ }
+
+ // run query
+ queryErrno = mysql_query(this->connection_, "SELECT @idToString");
+ // check for query error
+ if (queryErrno !=0) {
+ fprintf(stderr, "[Database] Error calling mysql function: %s\n",
+ mysql_error(this->connection_));
+ return id;
+ }
+
+ // clear query string
+ free(queryString);
+
+ // store mysql query result
+ result = mysql_store_result(this->connection_);
+
+ // get returned row
+ if ( (row = mysql_fetch_row(result)) == NULL ) {
+ fprintf(stderr, "[Database] No result returned by mysql query");
+ mysql_free_result(result);
+ return id;
+ }
+
+ // free mysql result
+ mysql_free_result(result);
+
+ if (row[0] == NULL) {
+ return id;
+ }
+
+ id = atoi(row[0]);
+
+ return id;
+
+}
+
+string Database::getAllInfo(int personId) {
+
+ // mysql query result
+ MYSQL_RES *result;
+ MYSQL_ROW row;
+ char* queryString = (char*)malloc(100*sizeof(char));
+ int queryErrno;
+ string info = "";
+ // prepare query
+ sprintf(queryString,"CALL GetPersonInformation(%d,@fname,@lname,"
+ "@bdate, @occupation, @phoneNr)",personId);
+
+ // run query
+ queryErrno = mysql_query(this->connection_, queryString);
+ // check for query error
+ if (queryErrno !=0) {
+ fprintf(stderr, "[Database] Error calling mysql function: %s\n",
+ mysql_error(this->connection_));
+ return info;
+ }
+
+ // run query
+ queryErrno = mysql_query(this->connection_, "SELECT @fname, @lname,"
+ " @phoneNr, @bdate, @occupation");
+ // check for query error
+ if (queryErrno !=0) {
+ fprintf(stderr, "[Database] Error calling mysql function: %s\n",
+ mysql_error(this->connection_));
+ return info;
+ }
+
+ // clear query string
+ free(queryString);
+
+ // store mysql query result
+ result = mysql_store_result(this->connection_);
+
+ // get returned row
+ if ( (row = mysql_fetch_row(result)) == NULL ) {
+ fprintf(stderr, "[Database] No result returned by mysql query");
+ mysql_free_result(result);
+ return info;
+ }
+
+ mysql_free_result(result);
+
+ // create result string: firstname lastname#phoneNr#birthdate#occupation
+ info.append(row[0]).append(" ").append(row[1]);
+ for (int i = 2 ; i < 5 ; i++) {
+
+ info.append("#");
+ if (row[i] == NULL) {
+ info.append("Unknown");
+ }
+ else {
+ info.append(row[i]);
+ }
+ }
+
+ return info;
+
+}
+
+string Database::getInfo(int personId, int infoType) {
+
+ // mysql query result
+ MYSQL_RES *result;
+ MYSQL_ROW row;
+ char* queryString = (char*)malloc(100*sizeof(char));
+ int queryErrno;
+ string info = "";
+
+ // prepare query
+ switch(infoType) {
+
+ case FIRSTNAME :
+ sprintf(queryString,"CALL GetPersonFirstName(%d,@info)",personId);
+ break;
+ case LASTNAME :
+ sprintf(queryString,"CALL GetPersonLastName(%d,@info)",personId);
+ break;
+ case BIRTHDATE :
+ sprintf(queryString,"CALL GetPersonBirthdate(%d,@info)",personId);
+ break;
+ case OCCUPATION :
+ sprintf(queryString,"CALL GetPersonOccupation(%d,@info)",personId);
+ break;
+ case PHONE_NR :
+ sprintf(queryString,"CALL GetPersonPhoneNr(%d,@info)",personId);
+ break;
+ }
+
+
+ // run query
+ queryErrno = mysql_query(this->connection_, queryString);
+ // check for query error
+ if (queryErrno !=0) {
+ fprintf(stderr, "[Database] Error calling mysql function: %s\n",
+ mysql_error(this->connection_));
+ return info;
+ }
+
+ // run query
+ queryErrno = mysql_query(this->connection_, "SELECT @info");
+ // check for query error
+ if (queryErrno !=0) {
+ fprintf(stderr, "[Database] Error calling mysql function: %s\n",
+ mysql_error(this->connection_));
+ return info;
+ }
+
+ // clear query string
+ free(queryString);
+
+ // store mysql query result
+ result = mysql_store_result(this->connection_);
+
+ // get returned row
+ if ( (row = mysql_fetch_row(result)) == NULL ) {
+ fprintf(stderr, "[Database] No result returned by mysql query");
+ mysql_free_result(result);
+ return info;
+ }
+
+ mysql_free_result(result);
+
+ // check if info is NULL
+ if (row[0] == NULL) {
+ return info;
+ }
+
+ // return requested information
+ return row[0];
+
+}
+
+void Database::insertNewPerson(int id, char* fname, char* lname,
+ char* bdate, char* occupation, char* phoneNr) {
+
+
+ // mysql query result
+ string queryString = "";
+ int queryErrno;
+
+ // prepare query
+ queryString.append("CALL InsertNewPerson(");
+ // append person Id
+ char idToString[5];
+ sprintf(idToString,"%d",id);
+ queryString.append(idToString).append(",");
+ // append firstName
+ queryString.append("'").append(fname).append("',");
+ // append lastName
+ if (strlen(lname) == 0)
+ queryString.append("NULL");
+ else
+ queryString.append("'").append(lname).append("'");
+ queryString.append(",");
+ // append birthdate
+ if (strlen(bdate) == 0)
+ queryString.append("NULL");
+ else
+ queryString.append("'").append(bdate).append("'");
+ queryString.append(",");
+ // append occupation
+ if (strlen(occupation) == 0)
+ queryString.append("NULL");
+ else
+ queryString.append("'").append(occupation).append("'");
+ queryString.append(",");
+ // append phone number
+ if (strlen(phoneNr) == 0)
+ queryString.append("NULL");
+ else
+ queryString.append("'").append(phoneNr).append("'");
+ queryString.append(")");
+
+
+
+ // run query
+ queryErrno = mysql_query(this->connection_, queryString.c_str());
+
+ // check for query error
+ if (queryErrno !=0) {
+ fprintf(stderr, "[Database] Error calling mysql function: %s\n",
+ mysql_error(this->connection_));
+ return;
+ }
+
+}
View
74 sql_database/Database.h
@@ -0,0 +1,74 @@
+/*
+ * File: Database.h
+ * Author: Elena Holobiuc
+ */
+
+#ifndef _DATABASE_H
+#define _DATABASE_H
+
+#include <mysql.h>
+
+#define HOST "localhost"
+#define USER "root"
+#define PASSWORD "password"
+#define DATABASE_NAME "Person"
+
+#define FIRSTNAME 0
+#define LASTNAME 1
+#define BIRTHDATE 2
+#define OCCUPATION 3
+#define PHONE_NR 4
+
+using namespace std;
+
+class Database {
+
+ // Construction & Destruction
+public:
+ Database();
+
+ ~Database();
+
+public:
+
+ /*
+ * Method that connects to mysql database
+ */
+ void connect();
+ /*
+ * Method that disconnects from mysql database
+ */
+ void disconnect();
+ /*
+ * Method that returns the id of a person from database or -1 if
+ * the person does not exist
+ */
+ int getPersonId(char* fname, char* lname);
+ /*
+ * Method that return all person information from database
+ */
+ string getAllInfo(int personId);
+ /*
+ * Method that returns a certain information from a database
+ * using a stored function
+ */
+ string getInfo(int personId, int infoType);
+ /*
+ * Method that inserts a new person into the database
+ * using a stored procedure
+ */
+ void insertNewPerson(int id, char* fname, char* lname,
+ char* bdate, char* occupation, char* phoneNr);
+
+
+private:
+
+ // current mysql connection
+ MYSQL *connection_;
+ MYSQL mysql_;
+
+};
+
+
+#endif /* _DATABASE_H */
+
View
11 sql_database/README
@@ -0,0 +1,11 @@
+DATABASE MODULE
+Author: Elena Holobiuc
+
+This module is used to call the stored procedures from the MySQL database.
+In the database_proc folder you can see the existing procedures.
+To call a procedure from the database in a C program create a new Database instance and call the connect method.
+In Database.h file you can see which function to use in order to call a specific procedure and the required parameters.
+You can modify the HOST, USER, PASSWORD and DATABASE from the header file.
+
+In order to populate the `persons` table with the people from person_database, run ./populateTable.sh MySqlUser
+
View
141 sql_database/database_proc/create_proc.sql
@@ -0,0 +1,141 @@
+USE Person;
+
+DROP PROCEDURE IF EXISTS InsertNewPerson;
+DELIMITER $$
+CREATE PROCEDURE InsertNewPerson(
+ IN id_ int(10),
+ IN fname_ VARCHAR(50),
+ IN lname_ VARCHAR(50),
+ IN bdate_ date,
+ IN occupation_ VARCHAR(50),
+ IN phoneNr_ VARCHAR(20))
+ BEGIN
+ INSERT into persons values ( id_,
+ fname_,
+ lname_,
+ bdate_,
+ occupation_,
+ phoneNr_
+ );
+ END$$
+DELIMITER ;
+
+DROP PROCEDURE IF EXISTS InsertExistingPersons;
+DELIMITER $$
+CREATE PROCEDURE InsertExistingPersons(
+ IN nrOfPersons int(10))
+ BEGIN
+ DECLARE i INT DEFAULT 1;
+ DECLARE fname VARCHAR(10);
+ DECLARE lname VARCHAR(20);
+ WHILE (i <= nrOfPersons) DO
+ SET fname = CONCAT("s",i);
+ SET lname = CONCAT("lastname",i);
+ CALL InsertNewPerson(i,fname,lname,NULL,NULL,NULL);
+ SET i = i + 1;
+ END WHILE;
+ END$$
+DELIMITER ;
+
+
+DROP PROCEDURE IF EXISTS GetPersonInformation;
+DELIMITER $$
+CREATE PROCEDURE GetPersonInformation(
+ IN id_ int(10),
+ OUT fname VARCHAR(50),
+ OUT lname VARCHAR(50),
+ OUT bdate date,
+ OUT job VARCHAR(50),
+ OUT nr VARCHAR(20))
+ BEGIN
+ SELECT firstname, lastname,
+ birthdate, occupation,
+ phoneNr INTO fname,
+ lname, bdate,
+ job, nr
+ FROM persons
+ WHERE id_ = personId;
+ END$$
+DELIMITER ;
+
+DROP PROCEDURE IF EXISTS GetPersonFirstName;
+DELIMITER $$
+CREATE PROCEDURE GetPersonFirstName(
+ IN id_ int(10),
+ OUT name VARCHAR(50))
+ BEGIN
+ SELECT firstname
+ INTO name
+ FROM persons
+ WHERE id_ = personId;
+ END$$
+DELIMITER ;
+
+DROP PROCEDURE IF EXISTS GetPersonID;
+DELIMITER $$
+CREATE PROCEDURE GetPersonID(
+ IN fname_ VARCHAR(50),
+ IN lname_ VARCHAR(50),
+ OUT id int(10))
+ BEGIN
+ SELECT personId
+ INTO id
+ FROM persons
+ WHERE fname_ = firstname AND
+ lname_ = lastname;
+ END$$
+DELIMITER ;
+
+DROP PROCEDURE IF EXISTS GetPersonLastName;
+DELIMITER $$
+CREATE PROCEDURE GetPersonLastName(
+ IN id_ int(10),
+ OUT name VARCHAR(50))
+ BEGIN
+ SELECT lastname
+ INTO name
+ FROM persons
+ WHERE id_ = personId;
+ END$$
+DELIMITER ;
+
+DROP PROCEDURE IF EXISTS GetPersonBirthdate;
+DELIMITER $$
+CREATE PROCEDURE GetPersonBirthdate(
+ IN id_ int(10),
+ OUT bdate date)
+ BEGIN
+ SELECT birthdate
+ INTO bdate
+ FROM persons
+ WHERE id_ = personId;
+ END$$
+DELIMITER ;
+
+DROP PROCEDURE IF EXISTS GetPersonOccupation;
+DELIMITER $$
+CREATE PROCEDURE GetPersonOccupation(
+ IN id_ int(10),
+ OUT job VARCHAR(50))
+ BEGIN
+ SELECT occupation
+ INTO job
+ FROM persons
+ WHERE id_ = personId;
+ END$$
+DELIMITER ;
+
+DROP PROCEDURE IF EXISTS GetPersonPhoneNr;
+DELIMITER $$
+CREATE PROCEDURE GetPersonPhoneNr(
+ IN id_ int(10),
+ OUT nr VARCHAR(20))
+ BEGIN
+ SELECT phoneNr
+ INTO nr
+ FROM persons
+ WHERE id_ = personId;
+ END$$
+DELIMITER ;
+
+
View
17 sql_database/database_proc/create_table.sql
@@ -0,0 +1,17 @@
+DROP DATABASE IF EXISTS `Person`;
+
+CREATE DATABASE `Person`;
+
+USE `Person`;
+
+DROP TABLE IF EXISTS `persons`;
+
+CREATE TABLE `persons` (
+ `personId` int(10) NOT NULL PRIMARY KEY AUTO_INCREMENT,
+ `firstname` varchar(50) NOT NULL,
+ `lastname` varchar(50),
+ `birthdate` date,
+ `occupation` varchar(50),
+ `phoneNr` varchar(20)
+) ENGINE=InnoDB DEFAULT CHARSET=latin1 ;
+
View
4 sql_database/database_proc/populate_table.sql
@@ -0,0 +1,4 @@
+USE Person;
+
+call InsertExistingPersons(40);
+
View
10 sql_database/initDatabase.sh
@@ -0,0 +1,10 @@
+#!/bin/sh
+username=$1
+
+mysql -u $username -p < "database_proc/create_table.sql"
+mysql -u $username -p < "database_proc/create_proc.sql"
+
+
+
+
+
View
5 sql_database/populateTable.sh
@@ -0,0 +1,5 @@
+#!/bin/sh
+username=$1
+
+mysql -u $username -p < "database_proc/populate_table.sql"
+
Please sign in to comment.
Something went wrong with that request. Please try again.