Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Improve accounting scripts #95

Merged
merged 28 commits into from
Nov 21, 2023
Merged
Show file tree
Hide file tree
Changes from 22 commits
Commits
Show all changes
28 commits
Select commit Hold shift + click to select a range
ff2baf3
Refactor code to allow for multiple components to be accounted
apdibbo Oct 4, 2023
5c2648f
Convert to python3
apdibbo Oct 4, 2023
aab6b24
Neaten up formatting of sql script
apdibbo Oct 4, 2023
23e5930
Refactor to use functions and to use a dedicated accounting db account
apdibbo Oct 4, 2023
c33022b
Reorganise directory structure and add readme
apdibbo Oct 4, 2023
0d8a421
Tidy up code
apdibbo Oct 4, 2023
211f3bc
Add back in needed import
apdibbo Oct 4, 2023
f5a78dc
Add functionality for manila and cinder accounting
apdibbo Oct 4, 2023
b7855aa
Add accounting for glance objects
apdibbo Oct 5, 2023
447c75a
Fix issue with Volumes and Shares being counted fractionally
apdibbo Oct 5, 2023
0373095
Tweaks and formatting for the readme
apdibbo Oct 5, 2023
260768c
Remove this dependency as it is not needed with Python3
apdibbo Oct 5, 2023
543fc5c
Fix typo in log message
apdibbo Oct 5, 2023
1664ace
Remove unneeded definer
apdibbo Oct 5, 2023
f4b8549
Add requirements file
apdibbo Oct 5, 2023
9cdc365
Add docstrings
apdibbo Oct 5, 2023
bedee2c
Generate approximate concurrency data
apdibbo Oct 5, 2023
a8a18fe
Add commenting to SQL scripts
apdibbo Oct 5, 2023
cf15b74
Abandon calculating concurrency for now
apdibbo Oct 5, 2023
1454f8d
Add back in field lost while trying to get concurrency working
apdibbo Oct 5, 2023
1e1aeed
Anish-ifying - addressing Anish's comments
apdibbo Oct 5, 2023
3fd0eef
Fix past accounting script
apdibbo Oct 5, 2023
a3f278f
More Docstrings
apdibbo Oct 23, 2023
14d5eb4
Deal with archived instances in the SQL
apdibbo Oct 23, 2023
be40495
Remove debugging line
apdibbo Oct 23, 2023
3fdb8c4
Add in storage backend
apdibbo Oct 23, 2023
ce05bf0
Fix variable name
apdibbo Oct 23, 2023
d0be537
Fix atomism
apdibbo Nov 1, 2023
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 2 additions & 0 deletions OpenStack-accounting/etc/thecount/thecount.conf.example
Original file line number Diff line number Diff line change
@@ -0,0 +1,2 @@
[database]
connection =mysql+pymysql://<dbusername>:<dbpassword>@<dbhost>:3306
23 changes: 23 additions & 0 deletions OpenStack-accounting/readme.md
apdibbo marked this conversation as resolved.
Show resolved Hide resolved
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
# TheCount


## Prerequisites

The following packages are required:
- python3-requests
- python36-sqlalchemy
- python36-PyMySQL

A database user with read access to the relevant databases for each OpenStack component you are accounting for

## Installation

Copy the scripts into `/usr/local/sbin` as shown in this repo
Create a config file with a database connection string in the format shown in `/etc/thecount/thecount.conf.example` in `/etc/thecount/thecount.conf`
Create the stored procedures in the `sql` directory appropriate db.

## Use

`now-accounting.sh` generates accounting for the last 24 hours - recommend setting up a cron to run this at midnight
`past-accounting.sh` takes a start date and an end date in the format "%Y-%m-%d %H:%M" to generate accounting for past usage where possible
`*-extract_accounting.py` takes a start date and an end date in the format "%Y-%m-%d %H:%M" to generate accounting for that component
3 changes: 3 additions & 0 deletions OpenStack-accounting/requirements.txt
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
python3-requests
python36-sqlalchemy
python36-PyMySQL
44 changes: 44 additions & 0 deletions OpenStack-accounting/sql/cinder_get_accounting_data.sql
apdibbo marked this conversation as resolved.
Show resolved Hide resolved
Original file line number Diff line number Diff line change
@@ -0,0 +1,44 @@
CREATE PROCEDURE `get_accounting_data`(IN starttime datetime, IN endtime datetime)
BEGIN
/*
This procedure generates accounting data for cinder
*/
SELECT
IFNULL(v.availability_zone, 'nova') AS AvailabilityZone,
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Just to double check, here is it only selecting nova as the availability zone if there isn't an availability zone for a given volume (e.g. volume doesn't have a ceph availability zone and is just null)?

Copy link
Collaborator Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yes, that is what that's doing

p.name AS Project,
pp.name AS Department,
COUNT(v.id) AS Volumes,
"Volume" as CinderType,
@VolumeSeconds:=SUM(IF(v.created_at <= starttime /* Captures Volumes which were created outside of the period deleted out of the period */
AND (v.deleted_at >= endtime
OR ISNULL(v.deleted_at)),
TIMESTAMPDIFF(SECOND,
starttime,
endtime),
IF(v.created_at <= starttime /* Captures Volumes which were created before the period and deleted during the period */
AND v.deleted_at < endtime,
TIMESTAMPDIFF(SECOND,
starttime,
v.deleted_at),
IF(v.created_at > starttime /* Captures Volumes which were created during the period and deleted outside the period */
AND (v.deleted_at >= endtime
OR ISNULL(v.deleted_at)),
TIMESTAMPDIFF(SECOND,
v.created_at,
endtime),
TIMESTAMPDIFF(SECOND,
v.created_at,
v.deleted_at))))) AS Volume_Seconds, /* Generates a count of seconds Volumes were running */
v.size AS Volume_GB
FROM
cinder.volumes v
JOIN
keystone.project p ON v.project_id = p.id
JOIN
keystone.project pp ON p.parent_id = pp.id
WHERE
v.created_at <= endtime
AND (v.deleted_at >= starttime
OR ISNULL(v.deleted_at))
GROUP BY v.availability_zone , v.size , p.name , pp.name;
END
48 changes: 48 additions & 0 deletions OpenStack-accounting/sql/glance_get_accounting_data.sql
apdibbo marked this conversation as resolved.
Show resolved Hide resolved
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
CREATE PROCEDURE `get_accounting_data`(IN starttime datetime, IN endtime datetime)
BEGIN
/*
This procedure generates accounting data for glance
*/
SELECT
p.name AS Project,
pp.name AS Department,
COUNT(g.id) AS Images,
ip.value as GlanceType,
if(il.value like "%rbd%", "RBD" ,if(il.value like "%swift%","OBJECT","UNKNONWN")) as StorageBackend,
@VolumeSeconds:=SUM(IF(g.created_at <= starttime /* Captures Images which were created outside of the period deleted out of the period */
apdibbo marked this conversation as resolved.
Show resolved Hide resolved
AND (g.deleted_at >= endtime
OR ISNULL(g.deleted_at)),
TIMESTAMPDIFF(SECOND,
starttime,
endtime),
IF(g.created_at <= starttime /* Captures Images which were created before the period and deleted during the period */
AND g.deleted_at < endtime,
TIMESTAMPDIFF(SECOND,
starttime,
g.deleted_at),
IF(g.created_at > starttime /* Captures Images which were created during the period and deleted outside the period */
AND (g.deleted_at >= endtime
OR ISNULL(g.deleted_at)),
TIMESTAMPDIFF(SECOND,
g.created_at,
endtime),
TIMESTAMPDIFF(SECOND,
g.created_at,
g.deleted_at))))) AS Image_Seconds, /* Generates a count of seconds Images were running */
g.size/(1024 * 1024 * 1024) AS Glance_GB
FROM
glance.images g
join
glance.image_properties ip on g.id = ip.image_id and ip.name = "image_type"
join
glance.image_locations il on g.id = il.image_id
JOIN
keystone.project p ON g.owner = p.id
JOIN
keystone.project pp ON p.parent_id = pp.id
WHERE
g.created_at <= endtime
AND (g.deleted_at >= starttime
OR g.deleted_at is null )
GROUP BY ip.value, g.size , p.name , pp.name,if(il.value like "%rbd%", "SIRIUS" ,if(il.value like "%swift%","ECHO","UNKNONWN"));
END
51 changes: 51 additions & 0 deletions OpenStack-accounting/sql/manila_get_accounting_data.sql
apdibbo marked this conversation as resolved.
Show resolved Hide resolved
Original file line number Diff line number Diff line change
@@ -0,0 +1,51 @@
CREATE PROCEDURE `get_accounting_data`(IN starttime datetime, IN endtime datetime)
BEGIN
/*
This procedure generates accounting data for manila
*/
SELECT
p.name AS Project,
pp.name AS Department,
maz.name AS Availability_zone,
st.name AS Share_type,
COUNT(m.id) AS Shares,
"Share" as ManilaType,
@ShareSeconds:=SUM(IF(m.created_at <= starttime /* Captures Shares which were created outside of the period deleted out of the period */
AND (m.deleted_at >= endtime
OR ISNULL(m.deleted_at)),
TIMESTAMPDIFF(SECOND,
starttime,
endtime),
IF(m.created_at <= starttime /* Captures Shares which were created before the period and deleted during the period */
AND m.deleted_at < endtime,
TIMESTAMPDIFF(SECOND,
starttime,
m.deleted_at),
IF(m.created_at > starttime /* Captures Shares which were created during the period and deleted outside the period */
AND (m.deleted_at >= endtime
OR ISNULL(m.deleted_at)),
TIMESTAMPDIFF(SECOND,
m.created_at,
endtime),
TIMESTAMPDIFF(SECOND,
m.created_at,
m.deleted_at))))) AS Share_Seconds, /* Generates a count of seconds Shares were running */
m.size AS Share_GB
FROM
manila.shares m
JOIN
manila.share_instances si ON m.id = si.share_id
JOIN
manila.share_types st ON si.share_type_id = st.id
JOIN
manila.availability_zones maz ON maz.id = si.availability_zone_id
JOIN
keystone.project p ON m.project_id = p.id
JOIN
keystone.project pp ON p.parent_id = pp.id
WHERE
m.created_at <= endtime
AND (m.deleted_at >= starttime
OR ISNULL(m.deleted_at))
GROUP BY m.size , p.name , pp.name , maz.name , st.name;
END
84 changes: 84 additions & 0 deletions OpenStack-accounting/sql/nova_get_accounting_data.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,84 @@
CREATE PROCEDURE `get_accounting_data`(IN starttime datetime, IN endtime datetime)
BEGIN
/*
Generates accounting data from the Nova database on various resources used
Some further comments below for the trickier bits
*/
SELECT
IFNULL(i.availability_zone, 'nova') AS AvailabilityZone,
p.name AS Project,
pp.name AS Department,
it.name AS Flavor,
COUNT(i.uuid) as VMs,
@VMSeconds:=SUM(IF(i.created_at <= starttime /* Captures VMs which were created outside of the period deleted out of the period */
AND (i.deleted_at >= endtime
OR ISNULL(i.deleted_at)),
TIMESTAMPDIFF(SECOND,
starttime,
endtime),
IF(i.created_at <= starttime /* Captures VMs which were created before the period and deleted during the period */
AND i.deleted_at < endtime,
TIMESTAMPDIFF(SECOND,
starttime,
i.deleted_at),
IF(i.created_at > starttime /* Captures VMs which were created during the period and deleted outside the period */
AND (i.deleted_at >= endtime
OR ISNULL(i.deleted_at)),
TIMESTAMPDIFF(SECOND,
i.created_at,
endtime),
TIMESTAMPDIFF(SECOND,
i.created_at,
i.deleted_at))))) AS VM_Seconds, /* Generates a count of seconds VMs were running */
'something' AS testingstuff,
apdibbo marked this conversation as resolved.
Show resolved Hide resolved
it.memory_mb AS Memory_MB,
it.vcpus AS VCPU,
it.swap AS Swap,
it.root_gb AS Root_GB,
it.ephemeral_gb AS Ephemeral_GB,
/* The below section extracts metadata to be used for accounting */
IFNULL((SELECT
value
FROM
nova_api.flavor_extra_specs es
WHERE
flavor_id = it.id
AND es.key LIKE '%per_unit_cost%'
AND es.key LIKE CONCAT('%',
CAST(YEAR(DATE_SUB(endtime, INTERVAL 3 MONTH))
AS NCHAR),
'%')
LIMIT 1),
0) AS Per_Unit_Cost,
IFNULL((SELECT
value
FROM
nova_api.flavor_extra_specs es
WHERE
flavor_id = it.id
AND es.key LIKE 'accounting:unit%'),
'core') AS Charge_Unit,
(SELECT
IFNULL(value, 0)
FROM
nova_api.flavor_extra_specs es
WHERE
flavor_id = it.id
AND es.key LIKE 'accounting:gpu_num%') AS GPU_Num
FROM
nova.instances i
JOIN
nova_api.flavors it ON i.instance_type_id = it.id
JOIN
keystone.project p ON i.project_id = p.id
JOIN
keystone.project pp ON p.parent_id = pp.id
WHERE
i.created_at <= endtime
AND (i.deleted_at >= starttime
OR ISNULL(i.deleted_at))
GROUP BY i.availability_zone , p.name , it.name , SUBSTRING(it.name,
1,
LOCATE('.', it.name))
;
END
85 changes: 85 additions & 0 deletions OpenStack-accounting/usr/local/sbin/accountinglib.py
apdibbo marked this conversation as resolved.
Show resolved Hide resolved
Original file line number Diff line number Diff line change
@@ -0,0 +1,85 @@
#!/usr/bin/python3
import time
import datetime
#from datetime import datetime,time
import json
import requests
import sys
import sqlalchemy
import logging
from sqlalchemy.sql import select
from sqlalchemy.orm import sessionmaker
import configparser

def get_logger(component):
apdibbo marked this conversation as resolved.
Show resolved Hide resolved
logging.basicConfig(filename="/var/log/thecount.log",
format=f'%(asctime)s {component} %(message)s',
filemode='a')
logger = logging.getLogger()
logger.setLevel(logging.INFO)
return logger

def ifnull(var, val):
'''Returns the second argument if the first argument is Null/None'''
if var is None:
return val
return var

def project_to_department(result):
'''Returns an appropriate department for a project'''
if "rally" in result["Project"]:
department = "STFC Cloud"
elif "efault" in result["Department"]:
department = result["Project"]
else:
department = result["Department"]
return department

def send_to_influx(datastring, logger):
'''Takes a datastring formatted to send to InfluxDBs rest api. Loads necessary config, sends and returns the response'''
# Read from config file
influx_parser = configparser.SafeConfigParser()
try:
influx_parser.read('/etc/influxdb.conf')
except Exceptions as exp:
logger.info(f'Unable to read from influx config file - {str(exp)}')
sys.exit(1)
try:
host = influx_parser.get('db', 'host')
database = influx_parser.get('db', 'database')
username = influx_parser.get('auth', 'username')
password = influx_parser.get('auth', 'password')
instance = influx_parser.get('cloud','instance')
except Exceptions as exp:
logger.info(f'Unable to parse influx config file - {str(exp)}')
sys.exit(1)
finaldatastring = datastring.replace("Accounting,","Accounting,instance="+instance+",")
logger.info(finaldatastring)
url = f'http://{host}/write?db={database}&precision=s'
response = requests.post(url,data=finaldatastring,auth=(username,password))
return response

def get_accounting_data(database,starttime,endtime, logger):
'''Takes a db name and a start and end time as arguments. Loads db config, creates a db connection and runs a stored procedure. Returns the results of the stored procedure'''
thecount_parser = configparser.RawConfigParser(strict=False)

try:
thecount_parser.read('/etc/thecount/thecount.conf')
except Exceptions as exp:
logger.info(f'Unable to read from thecount config file - {str(exp)}')
sys.exit(1)

try:
connectionstring = thecount_parser.get('database','connection') + '/' + database
except Exceptions as exp:
logger.info(f'Unable to parse thecount config file - {str(exp)}')
sys.exit(1)

engine = sqlalchemy.create_engine(connectionstring, encoding='utf-8')
connection = engine.connect()
sess = sessionmaker(bind=engine)()
query = f'call get_accounting_data( "{starttime}","{endtime}")'

logger.info(query)
results = sess.execute(query, { 'p1': starttime, 'p2': endtime })
return results
Loading